Skip to content

Commit

Permalink
HANA 2.0 SPS01
Browse files Browse the repository at this point in the history
HANA 2.0 SPS01
  • Loading branch information
saphanaacademy committed May 12, 2017
1 parent 233057b commit 454c84b
Show file tree
Hide file tree
Showing 15 changed files with 649 additions and 0 deletions.
43 changes: 43 additions & 0 deletions Code Snippets/PAL 132 Getting Started with HANA 20 SPS01.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
--------------------------------
-- RUN AGAINST SYSTEMDB DATABASE
--------------------------------

-- CHECK AFL PAL FUNCTIONS ARE INSTALLED
SELECT * FROM SYS.AFL_FUNCTIONS WHERE PACKAGE_NAME='PAL';

-- CHECK TENANT DATABASE EXISTS AND IS STARTED
SELECT * FROM SYS.M_DATABASES;

-- CREATE TENANT DATABASE (IF NEEDED)
CREATE DATABASE SHA SYSTEM USER PASSWORD Password1;

-- START TENANT DATABASE (IF NEEDED)
ALTER SYSTEM START DATABASE SHA;

-- ADD SCRIPT SERVER TO TENANT DATABASE
ALTER DATABASE SHA ADD 'scriptserver';


------------------------------
-- RUN AGAINST TENANT DATABASE
------------------------------

-- CHECK SCRIPT SERVER
SELECT * FROM SYS.M_SERVICES;

-- CREATE USER FOR PAL DEVELOPMENT
CREATE USER DEVUSER PASSWORD Password1;

-- AUTHORIZE ACCESS TO SYS VIEWS
GRANT CATALOG READ TO DEVUSER;

-- AUTHORIZE CREATION & REMOVAL OF PAL PROCEDURES
GRANT AFLPM_CREATOR_ERASER_EXECUTE TO DEVUSER;

-- AUTHORIZE EXECUTION OF PAL PROCEDURES
GRANT AFL__SYS_AFL_AFLPAL_EXECUTE TO DEVUSER;

-- IMPORT PAL SCHEMA

-- AUTHORIZE READ ACCESS TO DATA
GRANT SELECT ON SCHEMA PAL TO DEVUSER;
32 changes: 32 additions & 0 deletions Code Snippets/PAL 133 Real Time Scoring - Create Model State.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@
-- cleanup
DROP TYPE "T_STATE";
DROP TABLE "SIGNATURE";
CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_DROP"('DEVUSER', 'P_CMS');
DROP TABLE "STATE";

-- procedure setup
CREATE TYPE "T_STATE" AS TABLE ("NAME" VARCHAR(50), "VALUE" VARCHAR(100));
CREATE COLUMN TABLE "SIGNATURE" ("POSITION" INTEGER, "SCHEMA_NAME" NVARCHAR(256), "TYPE_NAME" NVARCHAR(256), "PARAMETER_TYPE" VARCHAR(7));
INSERT INTO "SIGNATURE" VALUES (1, 'DEVUSER', 'T_MODEL', 'IN');
INSERT INTO "SIGNATURE" VALUES (2, 'DEVUSER', 'T_PARAMS', 'IN');
INSERT INTO "SIGNATURE" VALUES (3, 'DEVUSER', 'T_STATE', 'OUT');
CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_CREATE"('AFLPAL', 'CREATE_PAL_MODEL_STATE', 'DEVUSER', 'P_CMS', "SIGNATURE");

-- table setup
CREATE COLUMN TABLE "STATE" LIKE "T_STATE";

-- runtime
DROP TABLE "#PARAMS";
CREATE LOCAL TEMPORARY COLUMN TABLE "#PARAMS" LIKE "T_PARAMS";
INSERT INTO "#PARAMS" VALUES ('ALGORITHM', 2, null, null); -- 1: SVM, 2: Random Forest
--INSERT INTO "#PARAMS" VALUES ('STATE_DESCRIPTION', null, null, 'Optional State Description');

TRUNCATE TABLE "STATE";

CALL "P_CMS" ("MODEL", "#PARAMS", "STATE") WITH OVERVIEW;

SELECT * FROM "STATE";

SELECT * FROM "SYS"."M_AFL_STATES";
SELECT * FROM "SYS"."M_AFL_FUNCTIONS";

Original file line number Diff line number Diff line change
@@ -0,0 +1,44 @@
-- cleanup
DROP TYPE "T_DATA";
DROP TYPE "T_PREDICT";
DROP TABLE "SIGNATURE";
CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_DROP"('DEVUSER', 'P_PWMS');
DROP TABLE "DATA";
DROP TABLE "PREDICT";

-- procedure setup
CREATE TYPE "T_DATA" AS TABLE ("ID" INTEGER, "POLICY" NVARCHAR(10), "AGE" INTEGER, "AMOUNT" INTEGER, "OCCUPATION" NVARCHAR(10));
CREATE TYPE "T_PREDICT" AS TABLE ("ID" INTEGER, "FRAUD" VARCHAR(1000), "SCORE" DOUBLE);
CREATE COLUMN TABLE "SIGNATURE" ("POSITION" INTEGER, "SCHEMA_NAME" NVARCHAR(256), "TYPE_NAME" NVARCHAR(256), "PARAMETER_TYPE" VARCHAR(7));
INSERT INTO "SIGNATURE" VALUES (1, 'DEVUSER', 'T_DATA', 'IN');
INSERT INTO "SIGNATURE" VALUES (2, 'DEVUSER', 'T_STATE', 'IN');
INSERT INTO "SIGNATURE" VALUES (3, 'DEVUSER', 'T_PARAMS', 'IN');
INSERT INTO "SIGNATURE" VALUES (4, 'DEVUSER', 'T_PREDICT', 'OUT');
CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_CREATE"('AFLPAL', 'PREDICT_WITH_PAL_MODEL_STATE', 'DEVUSER', 'P_PWMS', "SIGNATURE");

-- data setup
CREATE COLUMN TABLE "DATA" LIKE "T_DATA";
CREATE COLUMN TABLE "PREDICT" LIKE "T_PREDICT";

INSERT INTO "DATA" VALUES (1, 'Travel', 56, 350, 'IT');
INSERT INTO "DATA" VALUES (2, 'Vehicle', 26, 6230, 'Marketing');
INSERT INTO "DATA" VALUES (3, 'Home', 55, 2300, 'Marketing');
INSERT INTO "DATA" VALUES (4, 'Vehicle', 31, 2134, 'Marketing');
INSERT INTO "DATA" VALUES (5, 'Vehicle', 64, 1200, 'Sales');

-- runtime
DROP TABLE "#PARAMS";
CREATE LOCAL TEMPORARY COLUMN TABLE "#PARAMS" LIKE "T_PARAMS";
-- NO PARAMETERS

TRUNCATE TABLE "PREDICT";

CALL "P_PWMS" ("DATA", "STATE", "#PARAMS", "PREDICT") WITH OVERVIEW;

SELECT d.*, p."FRAUD", "SCORE"
FROM "DATA" d
INNER JOIN "PREDICT" p ON (p."ID"=d."ID")
;

SELECT * FROM "SYS"."M_AFL_STATES";
SELECT * FROM "SYS"."M_AFL_FUNCTIONS";
30 changes: 30 additions & 0 deletions Code Snippets/PAL 135 Real Time Scoring - Delete Model State.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,30 @@
-- cleanup
DROP TYPE "T_MESSAGE";
DROP TABLE "SIGNATURE";
CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_DROP"('DEVUSER', 'P_DMS');
DROP TABLE "MESSAGE";

-- procedure setup
CREATE TYPE "T_MESSAGE" AS TABLE ("ID" VARCHAR(50), "TIMESTAMP" VARCHAR(100), "ERROR_CODE" INTEGER, "MESSAGE" VARCHAR(200));
CREATE COLUMN TABLE "SIGNATURE" ("POSITION" INTEGER, "SCHEMA_NAME" NVARCHAR(256), "TYPE_NAME" NVARCHAR(256), "PARAMETER_TYPE" VARCHAR(7));
INSERT INTO "SIGNATURE" VALUES (1, 'DEVUSER', 'T_STATE', 'IN');
INSERT INTO "SIGNATURE" VALUES (2, 'DEVUSER', 'T_PARAMS', 'IN');
INSERT INTO "SIGNATURE" VALUES (3, 'DEVUSER', 'T_MESSAGE', 'OUT');
CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_CREATE"('AFLPAL', 'DELETE_PAL_MODEL_STATE', 'DEVUSER', 'P_DMS', "SIGNATURE");

-- table setup
CREATE COLUMN TABLE "MESSAGE" LIKE "T_MESSAGE";

-- runtime
DROP TABLE "#PARAMS";
CREATE LOCAL TEMPORARY COLUMN TABLE "#PARAMS" LIKE "T_PARAMS";
-- NO PARAMETERS

TRUNCATE TABLE "MESSAGE";

CALL "P_DMS" ("STATE", "#PARAMS", "MESSAGE") WITH OVERVIEW;

SELECT * FROM "MESSAGE";

SELECT * FROM "SYS"."M_AFL_STATES";
SELECT * FROM "SYS"."M_AFL_FUNCTIONS";
42 changes: 42 additions & 0 deletions Code Snippets/PAL 136 Statistics - One-Sample Median Test.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
-- cleanup
DROP TYPE "T_DATA";
DROP TYPE "T_PARAMS";
DROP TYPE "T_RESULTS";
DROP TABLE "SIGNATURE";
CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_DROP"('DEVUSER', 'P_ST');
DROP VIEW "V_DATA";
DROP TABLE "RESULTS";


-- procedure setup
CREATE TYPE "T_DATA" AS TABLE ("INCOME" DOUBLE);
CREATE TYPE "T_PARAMS" AS TABLE ("NAME" VARCHAR(60), "INTARGS" INTEGER, "DOUBLEARGS" DOUBLE, "STRINGARGS" VARCHAR(100));
CREATE TYPE "T_RESULTS" AS TABLE ("NAME" VARCHAR(60), "VALUE" DOUBLE);

CREATE COLUMN TABLE "SIGNATURE" ("POSITION" INTEGER, "SCHEMA_NAME" NVARCHAR(256), "TYPE_NAME" NVARCHAR(256), "PARAMETER_TYPE" VARCHAR(7));
INSERT INTO "SIGNATURE" VALUES (1, 'DEVUSER', 'T_DATA', 'IN');
INSERT INTO "SIGNATURE" VALUES (2, 'DEVUSER', 'T_PARAMS', 'IN');
INSERT INTO "SIGNATURE" VALUES (3, 'DEVUSER', 'T_RESULTS', 'OUT');

CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_CREATE"('AFLPAL', 'SIGNTEST', 'DEVUSER', 'P_ST', "SIGNATURE");

-- data & view setup
CREATE VIEW "V_DATA" AS
SELECT "INCOME"
FROM "PAL"."CUSTOMERS"
;
CREATE TABLE "RESULTS" LIKE "T_RESULTS";

-- runtime
DROP TABLE "#PARAMS";
CREATE LOCAL TEMPORARY COLUMN TABLE "#PARAMS" LIKE "T_PARAMS";
INSERT INTO "#PARAMS" VALUES ('THREAD_NUMBER', 4, null, null); -- default 1
INSERT INTO "#PARAMS" VALUES ('M0', null, 3.0, null); -- default 0
INSERT INTO "#PARAMS" VALUES ('CONFIDENCE_INTERVAL', null, 0.95, null); -- default 0.95
INSERT INTO "#PARAMS" VALUES ('TEST_TYPE', 0, null, null); -- 0: two sides, 1:less, 2: greater (default:0)

TRUNCATE TABLE "RESULTS";

CALL "P_ST" ("V_DATA", "#PARAMS", "RESULTS") WITH OVERVIEW;

SELECT * FROM "RESULTS";
42 changes: 42 additions & 0 deletions Code Snippets/PAL 137 Statistics - Wilcox Signed Rank Test.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
-- cleanup
DROP TYPE "T_DATA";
DROP TYPE "T_PARAMS";
DROP TYPE "T_RESULTS";
DROP TABLE "SIGNATURE";
CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_DROP"('DEVUSER', 'P_WST');
DROP VIEW "V_DATA";
DROP TABLE "RESULTS";


-- procedure setup
CREATE TYPE "T_DATA" AS TABLE ("INCOME" DOUBLE, "LOYALTY" DOUBLE);
CREATE TYPE "T_PARAMS" AS TABLE ("NAME" VARCHAR(60), "INTARGS" INTEGER, "DOUBLEARGS" DOUBLE, "STRINGARGS" VARCHAR(100));
CREATE TYPE "T_RESULTS" AS TABLE ("NAME" VARCHAR(60), "VALUE" DOUBLE);

CREATE COLUMN TABLE "SIGNATURE" ("POSITION" INTEGER, "SCHEMA_NAME" NVARCHAR(256), "TYPE_NAME" NVARCHAR(256), "PARAMETER_TYPE" VARCHAR(7));
INSERT INTO "SIGNATURE" VALUES (1, 'DEVUSER', 'T_DATA', 'IN');
INSERT INTO "SIGNATURE" VALUES (2, 'DEVUSER', 'T_PARAMS', 'IN');
INSERT INTO "SIGNATURE" VALUES (3, 'DEVUSER', 'T_RESULTS', 'OUT');

CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_CREATE"('AFLPAL', 'WILCOXTEST', 'DEVUSER', 'P_WST', "SIGNATURE");

-- data & view setup
CREATE VIEW "V_DATA" AS
SELECT "INCOME", "LOYALTY"
FROM "PAL"."CUSTOMERS"
;
CREATE TABLE "RESULTS" LIKE "T_RESULTS";

-- runtime
DROP TABLE "#PARAMS";
CREATE LOCAL TEMPORARY COLUMN TABLE "#PARAMS" LIKE "T_PARAMS";
INSERT INTO "#PARAMS" VALUES ('THREAD_NUMBER', 4, null, null); -- default 1
INSERT INTO "#PARAMS" VALUES ('MU', null, 3.0, null); -- default 0
INSERT INTO "#PARAMS" VALUES ('TEST_TYPE', 0, null, null); -- 0: two sides, 1:less, 2: greater (default:0)
INSERT INTO "#PARAMS" VALUES ('CORRECTION', 1, null, null); -- 0: no, 1: yes (default:1)

TRUNCATE TABLE "RESULTS";

CALL "P_WST" ("V_DATA", "#PARAMS", "RESULTS") WITH OVERVIEW;

SELECT * FROM "RESULTS";
43 changes: 43 additions & 0 deletions Code Snippets/PAL 138 Statistics - TTest.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
-- cleanup
DROP TYPE "T_DATA";
DROP TYPE "T_PARAMS";
DROP TYPE "T_RESULTS";
DROP TABLE "SIGNATURE";
CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_DROP"('DEVUSER', 'P_TT');
DROP VIEW "V_DATA";
DROP TABLE "RESULTS";


-- procedure setup
CREATE TYPE "T_DATA" AS TABLE ("INCOME" DOUBLE, "LOYALTY" DOUBLE);
CREATE TYPE "T_PARAMS" AS TABLE ("NAME" VARCHAR(60), "INTARGS" INTEGER, "DOUBLEARGS" DOUBLE, "STRINGARGS" VARCHAR(100));
CREATE TYPE "T_RESULTS" AS TABLE ("NAME" VARCHAR(60), "VALUE" DOUBLE);

CREATE COLUMN TABLE "SIGNATURE" ("POSITION" INTEGER, "SCHEMA_NAME" NVARCHAR(256), "TYPE_NAME" NVARCHAR(256), "PARAMETER_TYPE" VARCHAR(7));
INSERT INTO "SIGNATURE" VALUES (1, 'DEVUSER', 'T_DATA', 'IN');
INSERT INTO "SIGNATURE" VALUES (2, 'DEVUSER', 'T_PARAMS', 'IN');
INSERT INTO "SIGNATURE" VALUES (3, 'DEVUSER', 'T_RESULTS', 'OUT');

CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_CREATE"('AFLPAL', 'TTEST', 'DEVUSER', 'P_TT', "SIGNATURE");

-- data & view setup
CREATE VIEW "V_DATA" AS
SELECT "INCOME", "LOYALTY"
FROM "PAL"."CUSTOMERS"
;
CREATE TABLE "RESULTS" LIKE "T_RESULTS";

-- runtime
DROP TABLE "#PARAMS";
CREATE LOCAL TEMPORARY COLUMN TABLE "#PARAMS" LIKE "T_PARAMS";
INSERT INTO "#PARAMS" VALUES ('TEST_TYPE', 0, null, null); -- 0: two sides, 1:less, 2: greater (default:0)
INSERT INTO "#PARAMS" VALUES ('MU', null, 3.0, null); -- default 0
INSERT INTO "#PARAMS" VALUES ('PAIRED', 0, null, null); -- 0: no, 1: yes (default:0)
INSERT INTO "#PARAMS" VALUES ('VAR_EQUAL', 0, null, null); -- 0: no, 1: yes (default:0)
INSERT INTO "#PARAMS" VALUES ('CONF_LEVEL', null, 0.95, null); -- default 0.95

TRUNCATE TABLE "RESULTS";

CALL "P_TT" ("V_DATA", "#PARAMS", "RESULTS") WITH OVERVIEW;

SELECT * FROM "RESULTS";
51 changes: 51 additions & 0 deletions Code Snippets/PAL 139 Statistics - ANOVA One-Way.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,51 @@
-- cleanup
DROP TYPE "T_DATA";
DROP TYPE "T_PARAMS";
DROP TYPE "T_STATS";
DROP TYPE "T_ANOVA";
DROP TYPE "T_MULTICOMPARISON";
DROP TABLE "SIGNATURE";
CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_DROP"('DEVUSER', 'P_ANOVA');
DROP VIEW "V_DATA";
DROP TABLE "STATS";
DROP TABLE "ANOVA";
DROP TABLE "MULTICOMPARISON";

-- procedure setup
CREATE TYPE "T_DATA" AS TABLE ("CLASS" VARCHAR(50), "ATTR1" DOUBLE);
CREATE TYPE "T_PARAMS" AS TABLE ("NAME" VARCHAR(60), "INTARGS" INTEGER, "DOUBLEARGS" DOUBLE, "STRINGARGS" VARCHAR(100));
CREATE TYPE "T_STATS" AS TABLE ("GROUP" VARCHAR(60), "SAMPLES" INTEGER, "MEAN" DOUBLE, "STDDEV" DOUBLE);
CREATE TYPE "T_ANOVA" AS TABLE ("SOURCE" VARCHAR(60), "SUMSQUARES" DOUBLE, "DEGREESFREEDOM" DOUBLE, "MEANSQUARES" DOUBLE, "FRATIO" DOUBLE, "PVALUE" DOUBLE);
CREATE TYPE "T_MULTICOMPARISON" AS TABLE ("FIRST_GROUP" VARCHAR(60), "SECOND_GROUP" VARCHAR(60), "MEANDIFF" DOUBLE, "STDERR" DOUBLE, "PVALUE" DOUBLE, "CL_LOWER" DOUBLE, "CL_UPPER" DOUBLE);

CREATE COLUMN TABLE "SIGNATURE" ("POSITION" INTEGER, "SCHEMA_NAME" NVARCHAR(256), "TYPE_NAME" NVARCHAR(256), "PARAMETER_TYPE" VARCHAR(7));
INSERT INTO "SIGNATURE" VALUES (1, 'DEVUSER', 'T_DATA', 'IN');
INSERT INTO "SIGNATURE" VALUES (2, 'DEVUSER', 'T_PARAMS', 'IN');
INSERT INTO "SIGNATURE" VALUES (3, 'DEVUSER', 'T_STATS', 'OUT');
INSERT INTO "SIGNATURE" VALUES (4, 'DEVUSER', 'T_ANOVA', 'OUT');
INSERT INTO "SIGNATURE" VALUES (5, 'DEVUSER', 'T_MULTICOMPARISON', 'OUT');

CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_CREATE"('AFLPAL', 'ANOVAONEWAY', 'DEVUSER', 'P_ANOVA', "SIGNATURE");

-- data & view setup
CREATE VIEW "V_DATA" AS
SELECT "CLASS", "ATTR1"
FROM "PAL"."CLASSIFICATION"
;
CREATE TABLE "STATS" LIKE "T_STATS";
CREATE TABLE "ANOVA" LIKE "T_ANOVA";
CREATE TABLE "MULTICOMPARISON" LIKE "T_MULTICOMPARISON";

-- runtime
DROP TABLE "#PARAMS";
CREATE LOCAL TEMPORARY COLUMN TABLE "#PARAMS" LIKE "T_PARAMS";
INSERT INTO "#PARAMS" VALUES ('MULTCOMP_METHOD', 0, null, null); -- 0: Tukey-Kramer, 1: Bonferroni, 2: Dunn-Sidak, 3: Scheffe, 4: Fisher’s LSD (default:0)
INSERT INTO "#PARAMS" VALUES ('SIGNIFICANCE_LEVEL', null, 0.05, null); -- default 0.05 (0 < 1)

TRUNCATE TABLE "RESULTS";

CALL "P_ANOVA" ("V_DATA", "#PARAMS", "STATS", "ANOVA", "MULTICOMPARISON") WITH OVERVIEW;

SELECT * FROM "STATS";
SELECT * FROM "ANOVA";
SELECT * FROM "MULTICOMPARISON";
Original file line number Diff line number Diff line change
@@ -0,0 +1,58 @@
-- cleanup
DROP TYPE "T_DATA";
DROP TYPE "T_PARAMS";
DROP TYPE "T_STATS";
DROP TYPE "T_MAUCHLY";
DROP TYPE "T_ANOVA";
DROP TYPE "T_MULTICOMPARISON";
DROP TABLE "SIGNATURE";
CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_DROP"('DEVUSER', 'P_ANOVARM');
DROP VIEW "V_DATA";
DROP TABLE "STATS";
DROP TABLE "MAUCHLY";
DROP TABLE "ANOVA";
DROP TABLE "MULTICOMPARISON";

-- procedure setup
CREATE TYPE "T_DATA" AS TABLE ("ID" INTEGER, "LIFESPEND" DOUBLE, "NEWSPEND" DOUBLE, "INCOME" DOUBLE, "LOYALTY" DOUBLE);
CREATE TYPE "T_PARAMS" AS TABLE ("NAME" VARCHAR(60), "INTARGS" INTEGER, "DOUBLEARGS" DOUBLE, "STRINGARGS" VARCHAR(100));
CREATE TYPE "T_STATS" AS TABLE ("GROUP" VARCHAR(60), "SAMPLES" INTEGER, "MEAN" DOUBLE, "STDDEV" DOUBLE);
CREATE TYPE "T_MAUCHLY" AS TABLE ("NAME" VARCHAR(60), "VALUE" DOUBLE);
CREATE TYPE "T_ANOVA" AS TABLE ("SOURCE" VARCHAR(60), "SUMSQUARES" DOUBLE, "DEGREESFREEDOM" DOUBLE, "MEANSQUARES" DOUBLE, "FRATIO" DOUBLE, "PVALUE" DOUBLE, "PVALUE_GREENHOUSE_GEISSER" DOUBLE, "PVALUE_HUYNH_FELDT" DOUBLE, "PVALUE_LOWER_CORRECTION" DOUBLE);
CREATE TYPE "T_MULTICOMPARISON" AS TABLE ("FIRST_GROUP" VARCHAR(60), "SECOND_GROUP" VARCHAR(60), "MEANDIFF" DOUBLE, "STDERR" DOUBLE, "PVALUE" DOUBLE, "CL_LOWER" DOUBLE, "CL_UPPER" DOUBLE);

CREATE COLUMN TABLE "SIGNATURE" ("POSITION" INTEGER, "SCHEMA_NAME" NVARCHAR(256), "TYPE_NAME" NVARCHAR(256), "PARAMETER_TYPE" VARCHAR(7));
INSERT INTO "SIGNATURE" VALUES (1, 'DEVUSER', 'T_DATA', 'IN');
INSERT INTO "SIGNATURE" VALUES (2, 'DEVUSER', 'T_PARAMS', 'IN');
INSERT INTO "SIGNATURE" VALUES (3, 'DEVUSER', 'T_STATS', 'OUT');
INSERT INTO "SIGNATURE" VALUES (4, 'DEVUSER', 'T_MAUCHLY', 'OUT');
INSERT INTO "SIGNATURE" VALUES (5, 'DEVUSER', 'T_ANOVA', 'OUT');
INSERT INTO "SIGNATURE" VALUES (6, 'DEVUSER', 'T_MULTICOMPARISON', 'OUT');

CALL "SYS"."AFLLANG_WRAPPER_PROCEDURE_CREATE"('AFLPAL', 'ANOVAONEWAYRM', 'DEVUSER', 'P_ANOVARM', "SIGNATURE");

-- data & view setup
CREATE VIEW "V_DATA" AS
SELECT "ID", "LIFESPEND", "NEWSPEND", "INCOME", "LOYALTY"
FROM "PAL"."CUSTOMERS"
;
CREATE TABLE "STATS" LIKE "T_STATS";
CREATE TABLE "MAUCHLY" LIKE "T_MAUCHLY";
CREATE TABLE "ANOVA" LIKE "T_ANOVA";
CREATE TABLE "MULTICOMPARISON" LIKE "T_MULTICOMPARISON";

-- runtime
DROP TABLE "#PARAMS";
CREATE LOCAL TEMPORARY COLUMN TABLE "#PARAMS" LIKE "T_PARAMS";
INSERT INTO "#PARAMS" VALUES ('MULTCOMP_METHOD', 0, null, null); -- 0: Tukey-Kramer, 1: Bonferroni, 2: Dunn-Sidak, 3: Scheffe, 4: Fisher’s LSD (default:0)
INSERT INTO "#PARAMS" VALUES ('SIGNIFICANCE_LEVEL', null, 0.05, null); -- default 0.05 (0 < 1)
INSERT INTO "#PARAMS" VALUES ('SE_TYPE', 1, null, null); -- 0: all data, 1: groups compared (default:1)

TRUNCATE TABLE "RESULTS";

CALL "P_ANOVARM" ("V_DATA", "#PARAMS", "STATS", "MAUCHLY", "ANOVA", "MULTICOMPARISON") WITH OVERVIEW;

SELECT * FROM "STATS";
SELECT * FROM "MAUCHLY";
SELECT * FROM "ANOVA";
SELECT * FROM "MULTICOMPARISON";
Loading

0 comments on commit 454c84b

Please sign in to comment.