├── A02_Demo_Datenmodell.png ├── Listings ├── Chapter 10 │ ├── EN_Listing 10.1.sql │ ├── EN_Listing 10.2.sql │ ├── EN_Listing 10.3.sql │ ├── EN_Listing 10.5.sql │ ├── EN_Listing 10.6.sql │ ├── EN_Listing 10.7.sql │ └── EN_Listing 10.8.sql ├── Chapter 11 │ ├── EN_Listing 11.1.sql │ ├── EN_Listing 11.2.sql │ ├── EN_Listing 11.3.sql │ ├── EN_Listing 11.4.sql │ ├── EN_Listing 11.5.sql │ ├── EN_Listing 11.6.sql │ └── EN_Listing 11.7.sql ├── Chapter 2 │ ├── EN_Listing 2.1.sql │ ├── EN_Listing 2.10.sql │ ├── EN_Listing 2.12.sql │ ├── EN_Listing 2.16.sql │ ├── EN_Listing 2.19.sql │ ├── EN_Listing 2.2.sql │ ├── EN_Listing 2.20.sql │ ├── EN_Listing 2.21.sql │ ├── EN_Listing 2.22.sql │ ├── EN_Listing 2.23.sql │ ├── EN_Listing 2.24.sql │ ├── EN_Listing 2.25.sql │ ├── EN_Listing 2.26.sql │ ├── EN_Listing 2.27.sql │ ├── EN_Listing 2.28.sql │ ├── EN_Listing 2.29.sql │ ├── EN_Listing 2.3.sql │ ├── EN_Listing 2.30.sql │ ├── EN_Listing 2.31.sql │ ├── EN_Listing 2.32.sql │ ├── EN_Listing 2.33.sql │ ├── EN_Listing 2.34.sql │ ├── EN_Listing 2.35.sql │ ├── EN_Listing 2.36.sql │ ├── EN_Listing 2.37.sql │ ├── EN_Listing 2.38.sql │ ├── EN_Listing 2.39.sql │ ├── EN_Listing 2.4.sql │ ├── EN_Listing 2.40.sql │ ├── EN_Listing 2.41.sql │ ├── EN_Listing 2.5.sql │ ├── EN_Listing 2.6.sql │ ├── EN_Listing 2.7.sql │ ├── EN_Listing 2.8.sql │ └── EN_Listing 2.9.sql ├── Chapter 3 │ ├── EN_Listing 3.1.sql │ ├── EN_Listing 3.13.sql │ ├── EN_Listing 3.14.sql │ ├── EN_Listing 3.15.sql │ ├── EN_Listing 3.16.sql │ ├── EN_Listing 3.17.sql │ ├── EN_Listing 3.18.sql │ ├── EN_Listing 3.19.sql │ ├── EN_Listing 3.20.sql │ ├── EN_Listing 3.22.sql │ ├── EN_Listing 3.23.sql │ ├── EN_Listing 3.25.sql │ ├── EN_Listing 3.27.sql │ ├── EN_Listing 3.28.sql │ ├── EN_Listing 3.29.sql │ ├── EN_Listing 3.30.sql │ ├── EN_Listing 3.31.sql │ ├── EN_Listing 3.32.sql │ ├── EN_Listing 3.33.sql │ ├── EN_Listing 3.34.sql │ ├── EN_Listing 3.35.sql │ ├── EN_Listing 3.36.sql │ ├── EN_Listing 3.37.sql │ ├── EN_Listing 3.38.sql │ ├── EN_Listing 3.39.sql │ ├── EN_Listing 3.4.sql │ ├── EN_Listing 3.40.sql │ ├── EN_Listing 3.41.sql │ ├── EN_Listing 3.42.sql │ ├── EN_Listing 3.43.sql │ ├── EN_Listing 3.44.sql │ ├── EN_Listing 3.45.sql │ ├── EN_Listing 3.46.sql │ ├── EN_Listing 3.47.sql │ ├── EN_Listing 3.48.sql │ ├── EN_Listing 3.49.sql │ ├── EN_Listing 3.5.sql │ ├── EN_Listing 3.50.sql │ ├── EN_Listing 3.6.sql │ └── EN_Listing 3.7.sql ├── Chapter 4 │ ├── EN_Listing 4.1.sql │ ├── EN_Listing 4.10.sql │ ├── EN_Listing 4.14.sql │ ├── EN_Listing 4.15.sql │ ├── EN_Listing 4.16.sql │ ├── EN_Listing 4.18.sql │ ├── EN_Listing 4.19.sql │ ├── EN_Listing 4.2.sql │ ├── EN_Listing 4.20.sql │ ├── EN_Listing 4.21.sql │ ├── EN_Listing 4.22.sql │ ├── EN_Listing 4.23.sql │ ├── EN_Listing 4.24.sql │ ├── EN_Listing 4.25.sql │ ├── EN_Listing 4.26.sql │ ├── EN_Listing 4.27.sql │ ├── EN_Listing 4.28.sql │ ├── EN_Listing 4.29.sql │ ├── EN_Listing 4.3.sql │ ├── EN_Listing 4.30.sql │ ├── EN_Listing 4.31.sql │ ├── EN_Listing 4.32.sql │ ├── EN_Listing 4.33.sql │ ├── EN_Listing 4.34.sql │ ├── EN_Listing 4.35.sql │ ├── EN_Listing 4.36.sql │ ├── EN_Listing 4.37.sql │ ├── EN_Listing 4.38.sql │ ├── EN_Listing 4.39.sql │ ├── EN_Listing 4.4.sql │ ├── EN_Listing 4.40.sql │ ├── EN_Listing 4.5.sql │ ├── EN_Listing 4.6.sql │ ├── EN_Listing 4.7.sql │ └── EN_Listing 4.9.sql ├── Chapter 5 │ ├── EN_Listing 5.1.sql │ ├── EN_Listing 5.11.sql │ ├── EN_Listing 5.12.sql │ ├── EN_Listing 5.2.sql │ ├── EN_Listing 5.3.sql │ ├── EN_Listing 5.5.sql │ ├── EN_Listing 5.6.sql │ ├── EN_Listing 5.7.sql │ ├── EN_Listing 5.8.sql │ └── EN_Listing 5.9.sql ├── Chapter 6 │ ├── EN_Listing 6.10.sql │ ├── EN_Listing 6.11.sql │ ├── EN_Listing 6.12.sql │ ├── EN_Listing 6.13.sql │ ├── EN_Listing 6.15.sql │ ├── EN_Listing 6.16.sql │ ├── EN_Listing 6.17.sql │ ├── EN_Listing 6.18.sql │ ├── EN_Listing 6.2.sql │ ├── EN_Listing 6.20.sql │ ├── EN_Listing 6.21.sql │ ├── EN_Listing 6.22.sql │ ├── EN_Listing 6.23.sql │ ├── EN_Listing 6.24.sql │ ├── EN_Listing 6.25.sql │ ├── EN_Listing 6.26.sql │ ├── EN_Listing 6.28.sql │ ├── EN_Listing 6.29.sql │ ├── EN_Listing 6.3.sql │ ├── EN_Listing 6.30.sql │ ├── EN_Listing 6.31.sql │ ├── EN_Listing 6.32.sql │ ├── EN_Listing 6.33.sql │ ├── EN_Listing 6.34.sql │ ├── EN_Listing 6.35.sql │ ├── EN_Listing 6.37.sql │ ├── EN_Listing 6.38.sql │ ├── EN_Listing 6.39.sql │ ├── EN_Listing 6.4.sql │ ├── EN_Listing 6.40.sql │ ├── EN_Listing 6.41.sql │ ├── EN_Listing 6.42.sql │ ├── EN_Listing 6.43.sql │ ├── EN_Listing 6.44.sql │ ├── EN_Listing 6.45.sql │ ├── EN_Listing 6.46.sql │ ├── EN_Listing 6.47.sql │ ├── EN_Listing 6.48.sql │ ├── EN_Listing 6.5.sql │ ├── EN_Listing 6.6.sql │ ├── EN_Listing 6.7.sql │ ├── EN_Listing 6.8.sql │ └── EN_Listing 6.9.sql ├── Chapter 7 │ ├── EN_Listing 7.10.sql │ ├── EN_Listing 7.11.sql │ ├── EN_Listing 7.12.sql │ ├── EN_Listing 7.13.sql │ ├── EN_Listing 7.14.sql │ ├── EN_Listing 7.15.sql │ ├── EN_Listing 7.2.sql │ ├── EN_Listing 7.3.sql │ ├── EN_Listing 7.4.sql │ ├── EN_Listing 7.5.sql │ ├── EN_Listing 7.6.sql │ ├── EN_Listing 7.7.sql │ ├── EN_Listing 7.8.sql │ └── EN_Listing 7.9.sql ├── Chapter 8 │ ├── EN_Listing 8.1.abap │ ├── EN_Listing 8.10.abap │ ├── EN_Listing 8.11.abap │ ├── EN_Listing 8.13.abap │ ├── EN_Listing 8.14.abap │ ├── EN_Listing 8.5.abap │ ├── EN_Listing 8.6.abap │ ├── EN_Listing 8.7.cds │ └── EN_Listing 8.9.cds └── Chapter 9 │ ├── EN_Listing 9.1.sql │ ├── EN_Listing 9.2.sql │ ├── EN_Listing 9.3.sql │ ├── EN_Listing 9.4.sql │ ├── EN_Listing 9.6.sql │ ├── EN_Listing 9.7.sql │ ├── EN_Listing 9.8.sql │ └── EN_Listing 9.9.sql ├── README.md └── demo_data_model ├── 01_Create_Tables_EN.sql ├── 02_Create_Procedures_and_Functions_EN.sql ├── 03_Fill_Tables_EN.sql ├── 03_Fill_Tables_EN_2.sql ├── 04_Check_Installation_EN.sql ├── 05_Delete_Data_Model_EN.sql └── generate_analytical_data.sql /A02_Demo_Datenmodell.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/96b3425219d6cafbec7dd3d81f79120b35a674e2/A02_Demo_Datenmodell.png -------------------------------------------------------------------------------- /Listings/Chapter 10/EN_Listing 10.1.sql: -------------------------------------------------------------------------------- 1 | -- Listing 10.1.sql 2 | -- Example of complexity in simple queries 3 | 4 | SELECT id, 5 | -- format name 6 | lastname || ', ' || firstname AS name, 7 | -- Symbol for gender 8 | CASE 9 | WHEN sex = 'F' 10 | THEN NCHAR('9792') 11 | WHEN sex = 'M' 12 | THEN NCHAR('9794') 13 | ELSE '' 14 | END AS MW, 15 | -- add text for the team 16 | COALESCE(( 17 | SELECT team_text 18 | FROM team_text 19 | WHERE ID = team 20 | AND langu = 'DE' 21 | ), ( 22 | SELECT team_text 23 | FROM team_text 24 | WHERE ID = team 25 | AND langu = 'EN' 26 | ), '') AS team 27 | FROM users; 28 | -------------------------------------------------------------------------------- /Listings/Chapter 10/EN_Listing 10.2.sql: -------------------------------------------------------------------------------- 1 | -- Listing 10.2.sql 2 | -- Same query with outsourced coding 3 | 4 | SELECT id, 5 | udf_name_formatting(firstname, lastname) AS name, 6 | udf_symbol_for_gender(sex) AS mw, 7 | (SELECT text FROM udf_team_text() WHERE id = team) 8 | AS team 9 | FROM users ; 10 | -------------------------------------------------------------------------------- /Listings/Chapter 10/EN_Listing 10.3.sql: -------------------------------------------------------------------------------- 1 | -- Listing 10.3.sql 2 | -- The three functions used in Listing 10.2 3 | 4 | CREATE FUNCTION udf_name_formatting( 5 | iv_firstname NVARCHAR(20), 6 | iv_lastname NVARCHAR(20) 7 | ) 8 | RETURNS rv_name NVARCHAR(42) 9 | AS BEGIN 10 | rv_name = iv_lastname || ', ' || iv_firstname; 11 | END; 12 | 13 | CREATE FUNCTION udf_symbol_for_gender( 14 | iv_sex NVARCHAR(1) 15 | ) 16 | RETURNS rv_symbol NVARCHAR(1) 17 | AS BEGIN 18 | rv_symbol = CASE WHEN iv_sex = 'F' 19 | THEN NCHAR('9792') 20 | WHEN iv_sex = 'M' 21 | THEN NCHAR('9794') 22 | ELSE '' END; 23 | END; 24 | 25 | CREATE FUNCTION udf_team_text( ) 26 | RETURNS TABLE(id INT, text NVARCHAR(20)) 27 | AS BEGIN 28 | lt_team_id = SELECT DISTINCT id FROM TEAM_TEXT; 29 | 30 | RETURN 31 | SELECT input.id, 32 | COALESCE(de.team_text, 33 | en.team_text, 34 | '') AS text 35 | FROM :lt_team_id AS input 36 | LEFT OUTER JOIN team_text as de 37 | ON de.id = input.id 38 | AND de.langu = 'DE' 39 | LEFT OUTER JOIN team_text as en 40 | ON en.id = input.id 41 | AND en.langu = 'EN'; 42 | END; 43 | -------------------------------------------------------------------------------- /Listings/Chapter 10/EN_Listing 10.5.sql: -------------------------------------------------------------------------------- 1 | -- Listing 10.5.sql 2 | -- Example for splitting a query into several steps 3 | 4 | -- Original SELECT statement 5 | SELECT project, 6 | projects.title, 7 | SUM(tasks.planned_effort) AS planned_effort, 8 | SUM(tasks.effort) AS effort, 9 | ROUND(SUM(tasks.effort) 10 | /SUM(tasks.planned_effort)*100,0) 11 | || '%' AS perc, 12 | projects.estimated_effort 13 | FROM tasks 14 | LEFT OUTER JOIN projects 15 | ON projects.id=tasks.project 16 | WHERE tasks.status IN (SELECT id 17 | FROM status 18 | WHERE is_final = true) 19 | GROUP BY project, 20 | projects.title, 21 | projects.estimated_effort 22 | ORDER BY ROUND(SUM(tasks.effort) 23 | /SUM(tasks.planned_effort)*100,0); 24 | 25 | -- Divided into steps: 26 | DO BEGIN 27 | -- Inbound projection STATUS 28 | lt_status_in = 29 | SELECT id 30 | FROM status 31 | WHERE is_final = true; 32 | 33 | -- Inbound projection TASKS 34 | lt_tasks_in = 35 | SELECT project, 36 | planned_effort, 37 | effort 38 | FROM tasks 39 | WHERE status in (SELECT * FROM :lt_status_in); 40 | 41 | -- Aggregation of the TASKS on PROJECTS 42 | lt_tasks_aggr = 43 | SELECT project, 44 | SUM(planned_effort) AS planned_effort, 45 | SUM(effort) AS effort 46 | FROM :lt_tasks_in 47 | GROUP BY project; 48 | 49 | -- Calculation on TASKS 50 | lt_tasks_calc = 51 | SELECT *, 52 | ROUND(effort/planned_effort*100) as perc 53 | FROM :lt_tasks_aggr; 54 | 55 | -- Inbound projection PROJECTS 56 | lt_projects_in = 57 | SELECT id, 58 | title, 59 | estimated_effort 60 | FROM projects; 61 | 62 | -- JOIN-step 63 | lt_projects_tasks = 64 | SELECT tasks.*, 65 | projects.* 66 | FROM :lt_tasks_calc AS tasks 67 | LEFT OUTER JOIN :lt_projects_in as projects 68 | ON tasks.project = projects.id 69 | ORDER BY tasks.perc; 70 | 71 | -- Outbound projection 72 | SELECT project, 73 | title, 74 | planned_effort, 75 | effort, 76 | perc || '%' as perc, 77 | estimated_effort 78 | FROM :lt_projects_tasks; 79 | END; 80 | -------------------------------------------------------------------------------- /Listings/Chapter 10/EN_Listing 10.6.sql: -------------------------------------------------------------------------------- 1 | -- Listing 10.6.sql 2 | -- Example for abbreviations in SQLScript 3 | SELECT * 4 | FROM colors sizes; 5 | 6 | SELECT * 7 | FROM colors, sizes; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 10/EN_Listing 10.7.sql: -------------------------------------------------------------------------------- 1 | -- Listing 10.7.sql 2 | -- The same example without abbreviation 3 | 4 | SELECT * 5 | FROM colors AS sizes; 6 | 7 | SELECT * 8 | FROM colors CROSS JOIN sizes; 9 | -------------------------------------------------------------------------------- /Listings/Chapter 10/EN_Listing 10.8.sql: -------------------------------------------------------------------------------- 1 | -- Listing 10.8.sql 2 | -- Code for testing 3 | 4 | SET 'ABAPVARCHARMODE' = 'FALSE'; 5 | SELECT 'Peter' || ' ' || 'Mueller' FROM DUMMY; 6 | SET 'ABAPVARCHARMODE' = 'TRUE'; 7 | SELECT 'Peter' || ' ' || 'Mueller' FROM DUMMY; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 11/EN_Listing 11.1.sql: -------------------------------------------------------------------------------- 1 | -- Listing 11.1.sql 2 | -- Development cycle in one script 3 | 4 | --Delete database objects 5 | DROP TABLE test_square; 6 | DROP FUNCTION udf_square; 7 | 8 | --Create function 9 | CREATE FUNCTION udf_square(IN iv_value INT) 10 | RETURNS rv_result INT 11 | AS BEGIN 12 | rv_result = iv_value * iv_value; 13 | END; 14 | 15 | --Create testcases 16 | CREATE TABLE test_square(value INT, square INT); 17 | INSERT INTO test_square VALUES (0,0); 18 | INSERT INTO test_square VALUES (1,1); 19 | INSERT INTO test_square VALUES (2,4); 20 | INSERT INTO test_square VALUES (-1,1); 21 | INSERT INTO test_square VALUES (-2,4); 22 | 23 | --Execute testcases 24 | SELECT value, 25 | square AS expected_value, 26 | udf_square(value) AS result, 27 | CASE WHEN udf_square(value) = square 28 | THEN 'OK' 29 | ELSE 'Error' 30 | END AS testresult 31 | FROM test_square; 32 | -------------------------------------------------------------------------------- /Listings/Chapter 11/EN_Listing 11.2.sql: -------------------------------------------------------------------------------- 1 | -- Listing 11.2.sql 2 | -- Simple example for the TRACE statement 3 | 4 | DROP PROCEDURE pr_trace; 5 | CREATE PROCEDURE pr_trace( OUT ot_result tasks) 6 | AS BEGIN 7 | lt_tasks = SELECT * FROM tasks; 8 | 9 | ot_result = TRACE(:lt_tasks); 10 | END; 11 | 12 | DO BEGIN 13 | DECLARE lv_sql VARCHAR(1000); 14 | DECLARE lv_table VARCHAR(100); 15 | CALL pr_trace(?); 16 | SELECT * FROM SYS.SQLSCRIPT_TRACE; 17 | SELECT table_name INTO lv_table FROM SYS.SQLSCRIPT_TRACE; 18 | lv_sql = 'SELECT * FROM ' || lv_table || ';'; 19 | EXECUTE IMMEDIATE lv_sql; 20 | END; 21 | -------------------------------------------------------------------------------- /Listings/Chapter 11/EN_Listing 11.3.sql: -------------------------------------------------------------------------------- 1 | -- Listing 11.3.sql 2 | -- Two procedures for debugging 3 | 4 | DROP PROCEDURE A;DROP PROCEDURE B; 5 | CREATE PROCEDURE A (IN iv_id INT, OUT ot_users users) 6 | AS BEGIN 7 | ot_users = SELECT * 8 | FROM users 9 | WHERE id >= :iv_id 10 | and id <= :iv_id + 5; 11 | END; 12 | 13 | CREATE PROCEDURE B (OUT ot_users users) 14 | AS BEGIN 15 | CALL A(iv_id=>'1', ot_users=>lt_tmp1); 16 | CALL A(iv_id=>'20', ot_users=>lt_tmp20); 17 | ot_users = SELECT * FROM :lt_tmp1 18 | UNION 19 | SELECT * FROM :lt_tmp20; 20 | END; 21 | 22 | CALL B(?); 23 | -------------------------------------------------------------------------------- /Listings/Chapter 11/EN_Listing 11.4.sql: -------------------------------------------------------------------------------- 1 | -- Listing 11.4.sql 2 | -- Simple SQL query for performance analysis 3 | 4 | SELECT a.id AS task, 5 | a.title, 6 | b.firstname, 7 | b.lastname, 8 | b.email, 9 | t.team_text 10 | FROM tasks AS a 11 | LEFT OUTER JOIN users AS b 12 | ON a.assignee = b.id 13 | LEFT OUTER JOIN team_text AS t 14 | ON b.team = t.id; 15 | -------------------------------------------------------------------------------- /Listings/Chapter 11/EN_Listing 11.5.sql: -------------------------------------------------------------------------------- 1 | -- Listing 11.5.sql 2 | -- Example for using the EXPLAIN PLAN statement 3 | 4 | EXPLAIN PLAN FOR 5 | SELECT a.id AS task, 6 | a.title, 7 | b.firstname, 8 | b.lastname, 9 | b.email, 10 | t.team_text 11 | FROM tasks AS a 12 | LEFT OUTER JOIN users AS b 13 | ON a.assignee = b.id 14 | LEFT OUTER JOIN team_text AS t 15 | ON b.team = t.id; 16 | 17 | SELECT * FROM explain_plan_table; 18 | DELETE FROM explain_plan_table; 19 | -------------------------------------------------------------------------------- /Listings/Chapter 11/EN_Listing 11.6.sql: -------------------------------------------------------------------------------- 1 | -- Listing 11.6.sql 2 | -- Call of the SQLScript Code Analyzer for existing procedures 3 | 4 | DO BEGIN 5 | lt_rules = 6 | SELECT rule_namespace, 7 | rule_name, 8 | category 9 | FROM sqlscript_analyzer_rules; 10 | 11 | lt_objects = 12 | SELECT schema_name , 13 | procedure_name AS object_name, 14 | definition 15 | FROM procedures 16 | WHERE schema_name like 'JBRANDEIS'; 17 | 18 | CALL analyze_sqlscript_objects( :lt_objects, 19 | :lt_rules, 20 | lt_result_objects, 21 | lt_result_findings ); 22 | 23 | SELECT objects.*, 24 | findings.* 25 | FROM :lt_result_objects AS objects 26 | INNER JOIN :lt_result_findings AS findings 27 | ON objects.object_definition_id 28 | = findings.object_definition_id; 29 | END; 30 | -------------------------------------------------------------------------------- /Listings/Chapter 11/EN_Listing 11.7.sql: -------------------------------------------------------------------------------- 1 | -- Listing 11.7.sql 2 | -- Calling the SQLScript Code Analyzer for a new procedure to be created 3 | 4 | DO BEGIN 5 | lt_rules = 6 | SELECT rule_namespace, 7 | rule_name, 8 | category 9 | FROM sqlscript_analyzer_rules; 10 | 11 | CALL analyze_sqlscript_definition( 12 | ' 13 | CREATE procedure check_me(IN iv_value INT, 14 | OUT ov_value INT) 15 | AS BEGIN 16 | DECLARE lv_unused VARCHAR(3) default '' ''; 17 | ov_value = iv_value; 18 | END; 19 | ', 20 | :lt_rules, 21 | lt_result_findings ); 22 | SELECT * FROM :lt_result_findings; 23 | END; 24 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.1.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.1.sql 2 | --IF-Statement contains an INSERT-Statement 3 | 4 | 1 IF lv_counter > 0 5 | 2 THEN 6 | 3 INSERT INTO colors VALUES ('Purple'); 7 | 4 END IF; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.10.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.10.sql 2 | -- Table DUMMY for Testing Expressions 3 | 4 | SELECT TO_DATS('2016-01-01') FROM DUMMY; 5 | 6 | -- The same test with an anonymous block 7 | DO (OUT rv_result NVARCHAR(10) =>?) 8 | BEGIN 9 | rv_result = TO_DATS('2016-12-31'); 10 | END; 11 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.12.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.12.sql 2 | -- SELECT-Query with UDF 3 | 4 | SELECT a.id, 5 | udf_username(a.assignee), 6 | a.title, 7 | s.status_text 8 | FROM udf_tasks_in_status(4) AS a 9 | LEFT OUTER JOIN udf_status_texts('DE') AS s 10 | ON a.status = s.id; -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.16.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.16.sql 2 | -- Anonymous block with parameters 3 | 4 | DO (IN iv_status INT => 1, 5 | OUT ot_tasks TABLE ( id INT, 6 | title NVARCHAR(40) ) => ?) 7 | BEGIN 8 | ot_tasks = SELECT id, 9 | title 10 | FROM tasks 11 | WHERE status = :iv_status; 12 | END; -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.19.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.19.sql 2 | -- Example of creating, executing, and deleting a simple procedure 3 | 4 | CREATE PROCEDURE parameter_test ( 5 | 6 | -- Scalar data type as input parameter 7 | IN iv_project INT, 8 | 9 | -- Database table as type for an output parameter 10 | OUT ot_tasks tasks, 11 | 12 | -- A table type for an output parameter 13 | OUT ot_status_text id_text, 14 | 15 | -- Definition of the table type in the code: 16 | OUT ot_remaining_effort TABLE ( task INT, 17 | remaining_effort INT ) ) 18 | AS 19 | BEGIN 20 | ot_tasks = SELECT * 21 | FROM tasks 22 | WHERE project = :iv_project; 23 | 24 | ot_status_text = SELECT id, 25 | status_text AS TEXT 26 | FROM status_text; 27 | 28 | ot_remaining_effort = SELECT id AS task, 29 | planed_effort - effort 30 | AS remaining_effort 31 | FROM :ot_tasks; 32 | END; 33 | 34 | CALL parameter_test(2, ?, ?, ?); 35 | 36 | --DROP PROCEDURE parameter_test; -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.2.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.2.sql 2 | -- Example for different formatting 3 | 4 | SELECT col1,col2 FROM T1; 5 | SELECT col1, 6 | col2 7 | FROM T1 ; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.20.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.20.sql 2 | -- Definition of a procedure with default values 3 | 4 | CREATE PROCEDURE default_values ( 5 | IN iv_max_id INT DEFAULT 10, 6 | it_table tasks DEFAULT tasks ) 7 | AS 8 | BEGIN 9 | SELECT id, 10 | title 11 | FROM :it_table 12 | WHERE id <= :iv_max_id; 13 | END; 14 | 15 | --Calling the procedure without parameters 16 | call default_values(); 17 | 18 | --Clean up 19 | DROP PROCEDURE default_values; 20 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.21.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.21.sql 2 | -- Internal procedure call with schema specificatio 3 | DO BEGIN 4 | CALL jbrandeis.status_texts(iv_langu=>'EN', 5 | et_result=> lt_status_texts) ; 6 | END; 7 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.22.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.22.sql 2 | -- Internal procedure call without the keyword CALL 3 | 4 | DO BEGIN 5 | statustexts(iv_langu=>'DE', 6 | et_result=> lt_status_texts) ; 7 | END; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.23.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.23.sql 2 | -- Declaration and initialization of a new table variable when calling a procedur 3 | DO BEGIN 4 | statustexts(iv_langu=>'EN', 5 | et_result=>lt_status_texts) ; 6 | SELECT * FROM :lt_status_texts; 7 | END; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.24.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.24.sql 2 | -- Procedure call using the parameterposition 3 | 4 | DO BEGIN 5 | statustexts('EN',lt_status_texts) ; 6 | SELECT * FROM :lt_status_texts; 7 | END; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.25.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.25.sql 2 | -- Parameterization from the SQL console 3 | 4 | --Call without parameter name, see listing 19 5 | CALL parameter_test(2, ?, ?, ?); 6 | 7 | --The same call with named parameter 8 | CALL parameter_test(iv_project=>2, 9 | ot_tasks=>?, 10 | ot_status_text=>?, 11 | ot_remaining_effort=>?); 12 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.26.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.26.sql 2 | -- Syntax of the CREATE FUNCTION Statement 3 | CREATE FUNCTION 4 | [( 6 | [LANGUAGE SQLSCRIPT] 7 | [SQL SECURITY {DEFINER|INVOKER} ] 8 | [DEFAULT SCHEMA Defaultschema] 9 | [DETERMINISTIC] 10 | AS 11 | BEGIN 12 | 13 | END 14 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.27.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.27.sql 2 | -- Example of a scalar UDF 3 | 4 | CREATE FUNCTION udf_name ( iv_firstname NVARCHAR(20), 5 | iv_lastname NVARCHAR(20) ) 6 | RETURNS rv_name NVARCHAR(42) 7 | AS BEGIN 8 | rv_name = :iv_lastname || ', ' || :iv_firstname; 9 | END; 10 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.28.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.28.sql 2 | -- Example of a table UDF 3 | 4 | CREATE FUNCTION udf_status_texts (iv_langu VARCHAR(2)) 5 | RETURNS TABLE ( id INT, 6 | status_text VARCHAR(20) ) 7 | AS BEGIN 8 | RETURN SELECT id, 9 | status_text 10 | FROM status_text 11 | WHERE langu = :iv_langu; 12 | END; 13 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.29.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.29.sql 2 | -- Assignment of UDF results to local variables 3 | 4 | DO BEGIN 5 | DECLARE lv_name NVARCHAR(42); 6 | --Assignment of scalar UDFs to scalar variables 7 | lv_name = udf_name( 'Jörg', 8 | 'Brandeis' ); 9 | 10 | SELECT lv_name FROM dummy; 11 | 12 | --Assigning a Table UDF to a Table Variable 13 | lt_status_texts = SELECT * FROM udf_status_texts('E'); 14 | 15 | SELECT * FROM :lt_status_texts; 16 | END; 17 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.3.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.3.sql 2 | -- Example for literals in the sourcecode 3 | 4 | SELECT 'Jörg' AS string, 5 | N'Jörg' AS unicode, 6 | x'fff' AS binary, 7 | -10 AS integer, 8 | - 1.2345 AS decimal, 9 | - 17.126E30 AS float, 10 | 0xff AS hex, 11 | '2010-01-01' AS date_as_string, 12 | DATE'2017-11-10' AS date, 13 | '15:42:04.123' AS time_as_string, 14 | TIME'15:42:04.123' AS time, 15 | '2011-12-31 23:59:59' AS timestamp_string, 16 | TIMESTAMP'2011-12-31 23:59:59' AS timestamp 17 | FROM dummy; 18 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.30.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.30.sql 2 | -- UDF with multiple return values 3 | 4 | CREATE FUNCTION udf_now 5 | RETURNS rv_time TIME, 6 | rv_date DATE 7 | AS BEGIN 8 | rv_date = CURRENT_DATE; 9 | rv_time = CURRENT_TIME; 10 | END; 11 | 12 | SELECT udf_now().rv_date, 13 | udf_now().rv_time 14 | FROM DUMMY; 15 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.31.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.31.sql 2 | -- Simultaneous assignment of all return values of a UDF 3 | DO BEGIN 4 | DECLARE lv_time TIME; 5 | DECLARE lv_date DATE; 6 | 7 | (lv_time, lv_date) = udf_now(); 8 | 9 | SELECT lv_date, lv_time FROM DUMMY; 10 | END; 11 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.32.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.32.sql 2 | -- Frame of the UDF_shipping price function with pseudo code 3 | 4 | CREATE FUNCTION udf_shipping price ( 5 | iv_length INT, 6 | iv_width INT, 7 | iv_height INT, 8 | iv_weight INT, 9 | iv_als_small_Parcel VARCHAR(1), 10 | iv_is_online VARCHAR(1) 11 | ) 12 | RETURNS rv_price DEC(17,2), 13 | rv_message NVARCHAR(30) 14 | AS 15 | BEGIN 16 | --Determining the size category 17 | --determination of the belt dimension 18 | --price class determination 19 | --Deriving the price using the price class 20 | END; 21 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.33.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.33.sql 2 | -- Determination of the shipping price with an UDF 3 | 4 | CREATE FUNCTION udf_shipping_price ( 5 | iv_length INT, 6 | iv_width INT, 7 | iv_height INT, 8 | iv_weight INT, 9 | iv_is_small_Parcel VARCHAR(1), 10 | iv_is_online VARCHAR(1) 11 | ) 12 | RETURNS rv_price DEC(17,2), 13 | rv_message NVARCHAR(30) 14 | AS 15 | BEGIN 16 | DECLARE lv_size_category INT; 17 | DECLARE lv_price_class VARCHAR(3); 18 | DECLARE lv_belt_dimension INT; 19 | 20 | --Determining the size category 21 | lv_size_category = udf_size_category(:iv_length, 22 | :iv_width, 23 | :iv_height); 24 | 25 | --Determining the belt dimension 26 | lv_belt_dimension = udf_belt_dimension(:iv_length, 27 | :iv_width, 28 | :iv_height); 29 | 30 | --Determining the price class 31 | call pr_price_class(:lv_size_category, 32 | :iv_weight, 33 | :lv_belt_dimension, 34 | :iv_is_small_Parcel, 35 | lv_price_class, 36 | rv_message); 37 | 38 | --Deriving the price using the price class 39 | rv_price = udf_price(:lv_price_class, 40 | :iv_is_online); 41 | END; 42 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.34.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.34.sql 2 | -- Determination of the size category for the packages 3 | 4 | CREATE FUNCTION udf_size_category ( 5 | iv_length INT, 6 | iv_width INT, 7 | iv_height INT ) 8 | RETURNS rv_result INT 9 | AS 10 | BEGIN 11 | SELECT CASE 12 | WHEN :iv_length <= 30 13 | AND :iv_width <= 30 14 | AND :iv_height <= 15 15 | THEN 1 16 | WHEN :iv_length <= 60 17 | AND :iv_width <= 30 18 | AND :iv_height <= 15 19 | THEN 2 20 | WHEN :iv_length <= 120 21 | AND :iv_width <= 60 22 | AND :iv_height <= 60 23 | THEN 3 24 | ELSE 4 25 | END 26 | INTO rv_result 27 | FROM DUMMY; 28 | END; 29 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.35.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.35.sql 2 | -- Testcases for the function UDF_SIZE_CATEGORY 3 | 4 | SELECT udf_size_category(30, 30, 10) FROM DUMMY; 5 | SELECT udf_size_category(35, 30, 15) FROM DUMMY; 6 | SELECT udf_size_category(30, 30, 30) FROM DUMMY; 7 | SELECT udf_size_category(121, 30, 30) FROM DUMMY; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.36.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.36.sql 2 | -- Function for calculating the belt dimension 3 | 4 | CREATE FUNCTION udf_belt_dimension(iv_length INT, 5 | iv_width INT, 6 | iv_height INT ) 7 | RETURNS rv_result INT 8 | AS 9 | BEGIN 10 | rv_result = :iv_length 11 | + (2 * :iv_width) 12 | + (2 * :iv_height); 13 | END; 14 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.37.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.37.sql 2 | -- Derivation of price class and messages 3 | 4 | CREATE PROCEDURE pr_price_class ( 5 | iv_size_category INT, 6 | iv_weight INT, 7 | iv_belt_dimension INT, 8 | iv_is_small_parcel VARCHAR(1), 9 | OUT ov_price_class VARCHAR(3), 10 | OUT ov_message NVARCHAR(30) 11 | ) READS SQL DATA 12 | AS 13 | BEGIN 14 | SELECT CASE 15 | WHEN iv_belt_dimension > 300 16 | THEN 'PT4' 17 | WHEN iv_size_category <= 1 18 | AND iv_weight <= 1000 19 | AND iv_is_small_parcel = 'X' 20 | THEN 'PN1' 21 | WHEN iv_size_category <= 2 22 | AND iv_weight <= 2000 23 | AND iv_is_small_parcel = 'X' 24 | THEN 'PN2' 25 | WHEN iv_size_category <= 2 26 | AND iv_weight <= 2000 27 | THEN 'PT1' 28 | WHEN iv_size_category <= 3 29 | AND iv_weight <= 5000 30 | THEN 'PT2' 31 | WHEN iv_size_category <= 3 32 | AND iv_weight <= 10000 33 | THEN 'PT3' 34 | WHEN iv_size_category <= 3 35 | AND iv_weight <= 31500 36 | THEN 'PT4' 37 | ELSE 'NA' 38 | END 39 | INTO ov_price_class 40 | FROM DUMMY; 41 | 42 | SELECT CASE 43 | WHEN iv_size_category = 4 44 | THEN 'Dimensions to large' 45 | WHEN iv_weight > 31500 46 | THEN 'weight to high' 47 | WHEN iv_is_small_Parcel = 'X' 48 | AND :ov_price_class IN ('PT1','PT2','PT3','PT4') 49 | THEN 'Not as small parcel!' 50 | ELSE '' 51 | END 52 | INTO ov_message 53 | FROM DUMMY; 54 | 55 | IF ov_message <> '' 56 | THEN 57 | ov_price_class = 'NA'; 58 | END IF; 59 | END; 60 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.38.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.38.sql 2 | -- Price determination based on price class and online flag 3 | 4 | CREATE FUNCTION udf_price( iv_price_class VARCHAR(3), 5 | iv_is_online VARCHAR(1) ) 6 | RETURNS rv_price DEC(17, 2) 7 | AS BEGIN 8 | SELECT CASE :iv_is_online 9 | WHEN 'X' THEN CASE :iv_price_class 10 | WHEN 'PN1' THEN 3.89 11 | WHEN 'PN2' THEN 4.39 12 | WHEN 'PT1' THEN 4.99 13 | WHEN 'PT2' THEN 5.99 14 | WHEN 'PT3' THEN 8.49 15 | WHEN 'PT4' THEN 16.49 16 | ELSE 0 17 | END 18 | ELSE --store 19 | CASE :iv_price_class 20 | WHEN 'PN1' THEN 4 21 | WHEN 'PN2' THEN 4.5 22 | WHEN 'PT1' THEN 6.99 23 | WHEN 'PT2' THEN 6.99 24 | WHEN 'PT3' THEN 9.49 25 | WHEN 'PT4' THEN 16.49 26 | ELSE 0 27 | END 28 | END 29 | INTO rv_price 30 | FROM DUMMY; 31 | END; 32 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.39.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.39.sql 2 | -- Table for test data 3 | 4 | CREATE TABLE test_shipping_prices( 5 | length INT, 6 | width INT, 7 | height INT, 8 | weight INT, 9 | is_small_Parcel VARCHAR(1), 10 | is_online VARCHAR(1), 11 | expected_price DEC(17, 2) 12 | ); 13 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.4.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.4.sql 2 | -- Example for the simple identifieres 3 | 4 | SELECT id, 5 | status, 6 | title 7 | FROM tasks; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.40.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.40.sql 2 | -- Test data for shipping prices 3 | 4 | INSERT INTO test_shipping_prices VALUES 5 | (30,30,15,1000,'X','X',3.89); 6 | INSERT INTO test_shipping_prices VALUES 7 | (30,30,15,1000,'X','',4); 8 | INSERT INTO test_shipping_prices VALUES 9 | (60,30,15,1000,'X','X',4.39); 10 | INSERT INTO test_shipping_prices VALUES 11 | (60,30,15,1000,'X','',4.5); 12 | INSERT INTO test_shipping_prices VALUES 13 | (60,30,15,2000,'','X',4.99); 14 | INSERT INTO test_shipping_prices VALUES 15 | (60,30,15,2000,'','',6.99); 16 | INSERT INTO test_shipping_prices VALUES 17 | (61,30,15,2000,'','X',5.99); 18 | INSERT INTO test_shipping_prices VALUES 19 | (60,30,15,10001,'','X',16.49); 20 | INSERT INTO test_shipping_prices VALUES 21 | (120,60,60,2000,'','X',16.49); 22 | INSERT INTO test_shipping_prices VALUES 23 | (60,30,15,2000,'','X',4.99); 24 | INSERT INTO test_shipping_prices VALUES 25 | (61,30,15,2000,'','',6.99); 26 | INSERT INTO test_shipping_prices VALUES 27 | (60,30,15,10001,'','',16.49); 28 | INSERT INTO test_shipping_prices VALUES 29 | (120,60,60,2000,'','',16.49); 30 | INSERT INTO test_shipping_prices VALUES 31 | (60,30,15,10000,'','',9.49); 32 | INSERT INTO test_shipping_prices VALUES 33 | (60,30,15,40000,'','',0); 34 | INSERT INTO test_shipping_prices VALUES 35 | (60,30,15,3000,'X','X',0); 36 | INSERT INTO test_shipping_prices VALUES 37 | (121,60,60,2000,'','',0); 38 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.41.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.41.sql 2 | -- Execution of the tests 3 | 4 | SELECT 5 | expected_price, 6 | udf_shipping_price(length, 7 | width, 8 | height, 9 | weight, 10 | is_small_Parcel, 11 | is_online).rv_price 12 | - expected_price AS delta, 13 | udf_shipping_price(length, 14 | width, 15 | height, 16 | weight, 17 | is_small_Parcel, 18 | is_online).rv_message AS message 19 | FROM test_shipping_prices 20 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.5.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.5.sql 2 | -- access to local variables and parameters 3 | CREATE PROCEDURE get_name(IN id INT) 4 | AS BEGIN 5 | tmp = SELECT id, lastname, firstname FROM users; 6 | SELECT * FROM :tmp WHERE id = :id; 7 | END; 8 | CALL get_name(1); 9 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.6.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.6.sql 2 | -- Example for operator parentheses 3 | SELECT 4 | "PURCHASEORDERID", 5 | "PURCHASEORDERITEM", 6 | "PRODUCT.PRODUCTID", 7 | "CURRENCY", 8 | case 9 | when netamount <> 0 10 | --- with parentheses : 11 | --- then ((grossamount / netamount) * 100) - 100 12 | --- without parentheses : 13 | then grossamount / netamount * 100 - 100 14 | else 0 15 | end as tax, 16 | "GROSSAMOUNT", 17 | "NETAMOUNT", 18 | "TAXAMOUNT", 19 | "QUANTITY", 20 | "QUANTITYUNIT", 21 | "DELIVERYDATE" 22 | FROM "SAP_HANA_DEMO"."sap.hana.democontent.epm.data::PO.Item"; 23 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.7.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.7.sql 2 | -- Expressions in the field list 3 | SELECT 4 | -- Columname as an expression 5 | id, 6 | -- Concatination as an expression 7 | firstname || ' ' || lastname AS name, 8 | -- CASE-Expression.. 9 | CASE 10 | -- ..with a UDF expression 11 | WHEN sex = 'F' THEN NCHAR('9792') 12 | WHEN sex = 'M' THEN NCHAR('9794') 13 | ELSE '' 14 | END AS MW, 15 | -- SQL-function expression 16 | COALESCE(team, 0) as team 17 | FROM users; 18 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.8.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.8.sql 2 | -- Different typing of table variables 3 | 4 | CREATE TYPE id_text AS TABLE( id INT, 5 | text NVARCHAR(12)); 6 | 7 | DO BEGIN 8 | -- Type of a database table 9 | DECLARE lt_tab1 tasks; 10 | -- Type of a tabletype 11 | DECLARE lt_tab2 id_text; 12 | -- Table type defined in code with TABLE 13 | DECLARE lt_tab3 TABLE( id INT, 14 | col1 NVARCHAR(12) ); 15 | lt_tab1 = SELECT * FROM tasks; 16 | lt_tab2 = SELECT id, 17 | title as text 18 | FROM :lt_tab1; 19 | lt_tab3 = SELECT id, 20 | title as col1 21 | FROM :lt_tab1; 22 | SELECT * FROM :lt_tab1; 23 | SELECT * FROM :lt_tab2; 24 | SELECT * FROM :lt_tab3; 25 | END; 26 | -------------------------------------------------------------------------------- /Listings/Chapter 2/EN_Listing 2.9.sql: -------------------------------------------------------------------------------- 1 | -- Listing 2.9.sql 2 | -- Selection of a column with NULL values 3 | CREATE TABLE test_null( 4 | id INT, 5 | name VARCHAR(10) 6 | ); 7 | INSERT INTO test_null VALUES(1, 'Peter'); 8 | INSERT INTO test_null VALUES(2, 'Paul'); 9 | INSERT INTO test_null VALUES(3, 'Petra'); 10 | INSERT INTO test_null VALUES(4, 'Andrea'); 11 | INSERT INTO test_null(id) VALUES(5); 12 | 13 | SELECT * FROM test_null WHERE name LIKE 'P%'; 14 | 15 | SELECT * FROM test_null WHERE name NOT LIKE 'P%'; 16 | 17 | DROP TABLE test_null; --to delete the table 18 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.1.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.1.sql 2 | -- Implicite typing of a table variable 3 | 4 | DO BEGIN 5 | --Derivation of the table type from a table parameter 6 | CALL statustexts(iv_langu => 'DE', 7 | et_result => lt_statustext); 8 | 9 | 10 | --Derivation of the table type from the return structure of 11 | --the SELECT query 12 | lt_status = SELECT * FROM status; 13 | 14 | SELECT * FROM :lt_statustext; 15 | SELECT * FROM :lt_status; 16 | END; 17 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.13.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.13.sql 2 | -- Usage of a scalar UDF in the field list 3 | 4 | SELECT get_parcel_price(width, height, depth, weight ) 5 | FROM parcels; 6 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.14.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.14.sql 2 | -- Example of the usage of constant values and aggregate expressions 3 | 4 | DO BEGIN 5 | --Constant 1 as a value for COUNTER 6 | lt_tmp = SELECT 1 AS counter, 7 | planed_effort - effort AS remaining_effort 8 | FROM tasks 9 | WHERE status NOT IN (5, 6 ); 10 | 11 | --Aggregation on the column COUNTER 12 | SELECT sum(counter), 13 | sum(remaining_effort) 14 | FROM :lt_tmp; 15 | END; 16 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.15.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.15.sql 2 | -- Calculation of the effort for all projects 3 | 4 | SELECT project, 5 | sum(effort) 6 | FROM tasks 7 | GROUP BY project; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.16.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.16.sql 2 | -- Aggregation with grouping on two columns 3 | 4 | SELECT project, 5 | assignee, 6 | sum(effort) 7 | FROM tasks 8 | GROUP BY project, 9 | assignee 10 | ORDER BY project, 11 | assignee; 12 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.17.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.17.sql 2 | -- Concatination of the team name with the aggregate expression STRING_AGG 3 | 4 | SELECT langu, 5 | string_agg(team_text, ', ') 6 | FROM team_text 7 | GROUP BY langu; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.18.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.18.sql 2 | -- Enhancement of the example by the number of users 3 | 4 | SELECT STRING_AGG(team_text.team_text || '(' 5 | || cnt 6 | || ')', ', ') 7 | FROM ( 8 | SELECT team, 9 | count(*) AS cnt 10 | FROM users 11 | GROUP BY team 12 | ) AS b 13 | INNER JOIN team_text 14 | ON team_text.id = b.team 15 | WHERE langu = 'DE'; 16 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.19.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.19.sql 2 | -- Scalar subquery for the determination of a field 3 | 4 | SELECT 5 | schema_name, 6 | (SELECT 7 | COUNT(*) 8 | FROM tables 9 | WHERE schema_name=schemas.schema_name) 10 | AS table_count, 11 | (SELECT 12 | COUNT(*) 13 | FROM procedures 14 | WHERE schema_name=schemas.schema_name) 15 | AS procedure_count, 16 | schema_owner 17 | FROM schemas; 18 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.20.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.20.sql 2 | -- Comparison between COUNT as an aggregate expression and as a window function 3 | 4 | --Aggregate expression COUNT 5 | SELECT status, 6 | COUNT(*) AS counter 7 | FROM tasks 8 | GROUP BY status 9 | ORDER BY status; 10 | 11 | --Window Function COUNT 12 | SELECT id, 13 | status, 14 | COUNT(*) OVER (PARTITION BY status) AS counter 15 | FROM tasks 16 | ORDER BY id; 17 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.22.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.22.sql 2 | -- ORDER BY-clause in window functions 3 | 4 | SELECT id, 5 | status, 6 | COUNT(*) OVER (PARTITION BY status ORDER BY id) AS counter 7 | FROM tasks 8 | ORDER BY status; 9 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.23.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.23.sql 2 | -- Example with the window function lead 3 | 4 | SELECT id, 5 | project, 6 | LEAD(id) OVER ( PARTITION BY project 7 | ORDER BY id ) AS next_task 8 | FROM tasks 9 | ORDER BY id; 10 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.25.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.25.sql 2 | -- Cross Join over colors and sizes 3 | 4 | --Cross product with CROSS JOIN 5 | SELECT * 6 | FROM colors 7 | CROSS JOIN sizes; 8 | 9 | --Cross product with just a comma in the FROM-clause 10 | SELECT * 11 | FROM colors, 12 | sizes; 13 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.27.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/96b3425219d6cafbec7dd3d81f79120b35a674e2/Listings/Chapter 3/EN_Listing 3.27.sql -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.28.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.28.sql 2 | -- Example of the position of conditions 3 | 4 | SELECT * FROM records 5 | LEFT OUTER JOIN currencies 6 | ON records.currency = currencies.currency 7 | where currencies.currency <> 'EUR'; 8 | 9 | SELECT * FROM records 10 | LEFT OUTER JOIN currencies 11 | ON records.currency = currencies.currency 12 | and currencies.currency <> 'EUR'; 13 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.29.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.29.sql 2 | -- Example of the usage of comparison predicates 3 | 4 | --1. All tasks with a status lower/equal 3 5 | SELECT * 6 | FROM tasks 7 | WHERE status <= 3; 8 | 9 | --2. All tasks in the status 1, 2 or 4 10 | SELECT * 11 | FROM tasks 12 | WHERE status = ANY ( 1, 2, 4 ); 13 | 14 | --3. All tasks in a final status 15 | SELECT * 16 | FROM tasks 17 | WHERE status = ANY ( SELECT id 18 | FROM status 19 | WHERE is_final = true ); 20 | 21 | --4. All tasks that are not in a final status 22 | SELECT * 23 | FROM tasks 24 | WHERE status <> ALL ( SELECT id 25 | FROM status 26 | WHERE is_final = true ); 27 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.30.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.30.sql 2 | -- Usate of NOT LIKE 3 | 4 | --1. Negation of the whole predicate 5 | SELECT count(*) 6 | FROM tasks 7 | WHERE NOT ( title LIKE '%lorem%' ); 8 | 9 | --2. Equivalent query with NOT LIKE 10 | SELECT count(*) 11 | FROM tasks 12 | WHERE title NOT LIKE '%lorem%'; 13 | 14 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.31.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.31.sql 2 | -- Comparison with LIKE and ESCAPE 3 | 4 | SELECT table_name 5 | FROM tables 6 | WHERE table_name LIKE 'P$_%' ESCAPE '$' 7 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.32.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.32.sql 2 | -- Comparison with BETWEEN 3 | 4 | --1. Comparison with BETWEEN 5 | SELECT * 6 | FROM users 7 | WHERE id BETWEEN 5 AND 10; 8 | 9 | --2. The same query with comparison predicates 10 | SELECT * 11 | FROM users 12 | WHERE id >= 5 13 | AND id <= 10; 14 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.33.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.33.sql 2 | -- Example for the usage of the IN-predicate 3 | 4 | --1. Check of one column with multiple values with OR 5 | SELECT * 6 | FROM users 7 | WHERE firstname = 'Ozzy' 8 | OR firstname = 'Alfredo' 9 | OR firstname = 'Troy'; 10 | 11 | --2. Analog query with the IN predicate 12 | SELECT * 13 | FROM users 14 | WHERE firstname IN ( 'Ozzy', 'Alfredo', 'Troy' ); 15 | 16 | 17 | --3. Use of a subquery with the IN predicate: 18 | --Users who currently have no task assigned to them. 19 | SELECT * 20 | FROM users 21 | WHERE id NOT IN ( SELECT DISTINCT assignee 22 | FROM tasks ); 23 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.34.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.34.sql 2 | -- Examples for the EXIST-predicate 3 | 4 | --1. query with EXISTS predicate 5 | --All users with at least one task 6 | SELECT * 7 | FROM users 8 | WHERE EXISTS ( 9 | SELECT assignee 10 | FROM tasks 11 | WHERE tasks.assignee = users.id ); 12 | 13 | --2. query with NOT EXISTS 14 | --Tasks whose status is not in the status table 15 | SELECT * 16 | FROM tasks 17 | WHERE NOT EXISTS ( 18 | SELECT id 19 | FROM status 20 | WHERE status.id = tasks.status ); 21 | 22 | --3. Same query with NOT IN 23 | SELECT * 24 | FROM tasks 25 | WHERE status NOT IN ( 26 | SELECT id 27 | FROM status ); 28 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.35.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.35.sql 2 | -- CASE-Expression in a WHERE-clause 3 | 4 | CREATE TABLE t_fiscper (fiscper3 VARCHAR(3)); 5 | 6 | INSERT INTO t_fiscper VALUES ('000'); 7 | INSERT INTO t_fiscper VALUES ('001'); 8 | INSERT INTO t_fiscper VALUES ('002'); 9 | INSERT INTO t_fiscper VALUES ('003'); 10 | 11 | CREATE PROCEDURE where_clause (IN iv_fiscper3 VARCHAR(3)) 12 | AS 13 | BEGIN 14 | SELECT * 15 | FROM t_fiscper 16 | WHERE fiscper3 LIKE CASE :iv_fiscper3 17 | WHEN '' 18 | THEN '%' 19 | ELSE :iv_fiscper3 20 | END 21 | AND fiscper3 IS NOT NULL; 22 | END; 23 | 24 | CALL where_clause(''); 25 | CALL where_clause('000'); 26 | CALL where_clause('001'); 27 | 28 | DROP TABLE t_fiscper; 29 | DROP PROCEDURE where_clause; 30 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.36.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.36.sql 2 | -- Check for NULL 3 | 4 | --1. check with the NULL predicate 5 | SELECT * 6 | FROM users 7 | WHERE firstname IS NULL; 8 | 9 | --2. Attention! This query returns a different result! 10 | SELECT * 11 | FROM users 12 | WHERE firstname = NULL; --Wrong! Do not use! 13 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.37.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.37.sql 2 | -- fuzzy search with the CONTAINS-predicate 3 | 4 | --1. fuzzy search for a character string 5 | SELECT * 6 | FROM users 7 | WHERE CONTAINS ( ( firstname, lastname, email ), 8 | 'andy', 9 | FUZZY(0.3) ); 10 | 11 | --2. fuzzy search for multiple strings 12 | SELECT * 13 | FROM users 14 | WHERE CONTAINS ( *, 15 | 'andy OR anette', 16 | FUZZY(0.5) ); 17 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.38.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.38.sql 2 | -- SELECT-query with a WITH-clause 3 | 4 | --First a named query is created 5 | WITH lt_tasks_to_check AS ( 6 | SELECT a.id, 7 | b.firstname || ' ' || b.lastname AS assignee, 8 | a.title, 9 | a.due_date, 10 | a.status, 11 | a.planed_effort, 12 | a.effort 13 | FROM tasks AS a 14 | INNER JOIN users AS b 15 | ON a.assignee = b.id 16 | WHERE ( a.status NOT IN ( 5, 6 ) ) ) 17 | 18 | --This named query will be used later 19 | SELECT to_nvarchar('Overdue') AS reason, 20 | * 21 | FROM lt_tasks_to_check 22 | WHERE due_date < to_date('2017-12-01') 23 | UNION ALL 24 | SELECT to_nvarchar('Check estimate') AS reason, 25 | * 26 | FROM lt_tasks_to_check 27 | WHERE planed_effort <= effort * 1.1; 28 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.39.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.39.sql 2 | -- Using table variables instead of the WITH clause 3 | 4 | DO BEGIN 5 | --Definition of a table variable by the SELECT query 6 | lt_tasks_to_check = SELECT a.id, 7 | b.firstname || ' ' || b.lastname AS assignee, 8 | a.title, 9 | a.due_date, 10 | a.status, 11 | a.planed_effort, 12 | a.effort 13 | FROM tasks AS a 14 | INNER JOIN users AS b 15 | ON a.assignee = b.id 16 | WHERE (a.status NOT IN (5, 6)); 17 | 18 | --Usage of the table variable in both querys 19 | SELECT to_nvarchar('Overdue') AS reason, 20 | * 21 | FROM :lt_tasks_to_check 22 | WHERE due_date < to_date('2017-12-01') 23 | UNION ALL 24 | SELECT to_nvarchar('Check estimate') AS reason, 25 | * 26 | FROM :lt_tasks_to_check 27 | WHERE planed_effort <= effort * 1.1; 28 | END; 29 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.4.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.4.sql 2 | -- Example of the usage of alias names for columns 3 | 4 | SELECT '1' AS counter, 5 | "NAME.FIRST" AS firstname, 6 | "NAME.LAST" AS lastname 7 | FROM "sap.hana.democontent.epm.data::MD.Employees"; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.40.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.40.sql 2 | -- Example of a CASE-Expression in the GROUP BY-clause 3 | 4 | SELECT CASE 5 | WHEN due_date < to_date('2017-12-01') 6 | AND status NOT IN ( 5, 6 ) 7 | THEN 'to check' 8 | ELSE 'OK' 9 | END AS "Check?", 10 | count(*) AS cnt 11 | FROM tasks 12 | GROUP BY CASE 13 | WHEN due_date < to_date('2017-12-01') 14 | AND status NOT IN ( 5, 6 ) 15 | THEN 'to check' 16 | ELSE 'OK' 17 | END; 18 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.41.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.41.sql 2 | -- Separation of CASE and GROUP BY 3 | 4 | DO BEGIN 5 | --1. New column with the CASE-expression 6 | lt_select = SELECT CASE 7 | WHEN due_date < to_date('2017-12-01') 8 | AND status NOT IN ( 5, 6 ) 9 | THEN 'to check' 10 | ELSE 'OK' 11 | END AS "Check?" 12 | FROM tasks; 13 | --2. Grouping by the new column 14 | SELECT "Check?", 15 | count(*) as cnt 16 | FROM :lt_select 17 | GROUP BY "Check?"; 18 | END; 19 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.42.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.42.sql 2 | -- Usage of GROUPING SETS to form totals rows 3 | 4 | DO BEGIN 5 | lt_aggregation = SELECT assignee, 6 | status, 7 | count(*) AS cnt 8 | FROM tasks 9 | GROUP BY GROUPING SETS( 10 | ( status, assignee ), 11 | ( assignee ) ) 12 | ORDER BY assignee, 13 | status NULLS LAST; 14 | 15 | SELECT b.firstname || ' ' || b.lastname AS assignee, 16 | coalesce(s.status_text, ' Summe') AS status, 17 | aggr.cnt 18 | FROM :lt_aggregation AS aggr 19 | LEFT JOIN users AS b --Reading the user data 20 | ON aggr.assignee = b.id 21 | LEFT JOIN status_text AS s --Reading the status texts 22 | ON aggr.status = s.id 23 | AND s.langu = 'DE'; 24 | END; 25 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.43.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.43.sql 2 | -- Aggregation with GROUP BY- and HAVING-clause 3 | 4 | SELECT assignee, 5 | avg(planed_effort) 6 | FROM tasks 7 | GROUP BY assignee 8 | HAVING count(*) > 5; 9 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.44.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.44.sql 2 | -- Sorting with ORDER BY 3 | 4 | --1. Sorting by column name 5 | SELECT * 6 | FROM tasks 7 | ORDER BY planed_effort, 8 | effort; 9 | 10 | --2. Sorting by column number 11 | SELECT * 12 | FROM tasks 13 | ORDER BY 7, 14 | 8; 15 | 16 | --3. Sorting by an expression 17 | SELECT id, 18 | title 19 | FROM tasks 20 | ORDER BY planed_effort - effort DESC; 21 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.45.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.45.sql 2 | -- Usage of UNION and UNION ALL 3 | 4 | --Query with UNION: Duplicates are removed 5 | SELECT 'A' AS column1, 6 | 'B' AS column2 7 | FROM DUMMY 8 | UNION 9 | SELECT 'A' AS column1, 10 | 'B' AS column2 11 | FROM DUMMY; 12 | 13 | --Second query with UNION ALL without removing duplicates 14 | SELECT 'A' AS column1, 15 | 'B' AS column2 16 | FROM DUMMY 17 | UNION ALL 18 | SELECT 'A' AS column1, 19 | 'B' AS column2 20 | FROM DUMMY; 21 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.46.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.46.sql 2 | -- Example for the usage of INTERSECT 3 | 4 | --All users, that are project managers and with an 5 | --assigned task. 6 | --First aproach with INTERSECT: 7 | SELECT assignee 8 | FROM tasks 9 | INTERSECT 10 | SELECT project_manager 11 | FROM projects; 12 | 13 | --And secondly with an INNER JOIN: 14 | SELECT DISTINCT assignee 15 | FROM tasks 16 | INNER JOIN projects 17 | ON assignee = project_manager; 18 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.47.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.47.sql 2 | -- Subtraction of sets with EXCEPT and NOT EXISTS 3 | 4 | --Query of all assignees of tasks, without project managers 5 | --First with EXCEPT: 6 | SELECT assignee 7 | FROM tasks 8 | EXCEPT 9 | SELECT project_manager 10 | FROM projects; 11 | 12 | --And the same query with NOT EXISTS 13 | SELECT DISTINCT assignee 14 | FROM tasks AS a 15 | WHERE NOT EXISTS ( 16 | SELECT id 17 | FROM projects AS p 18 | WHERE p.project_manager = a.assignee ); 19 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.48.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.48.sql 2 | -- Example for subqueries 3 | 4 | --1. Scalar subquery 5 | SELECT * 6 | FROM tasks 7 | WHERE status = ( 8 | SELECT max(id) 9 | FROM status ); 10 | 11 | --2. Column-subquery 12 | SELECT * 13 | FROM tasks 14 | WHERE status IN ( 15 | SELECT id 16 | FROM status 17 | WHERE is_final = true ); 18 | 19 | --3. Table-subquery 20 | SELECT b.firstname || ' ' || b.lastname AS PL, 21 | p.title 22 | FROM ( 23 | SELECT * 24 | FROM projects 25 | WHERE title LIKE 'F%' ) AS p 26 | INNER JOIN users AS b 27 | ON p.project_manager = b.id; 28 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.49.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.49.sql 2 | -- Usage of table- and column alias 3 | 4 | SELECT tasks.id AS task_id, 5 | tasks.title AS task_title, 6 | assignee.id AS assignee_id, 7 | assignee.firstname 8 | || ' ' 9 | || assignee.lastname AS assignee_name, 10 | project_manager.id AS project_manager_id, 11 | project_manager.firstname 12 | || ' ' 13 | || project_manager.lastname AS project_manager_name 14 | FROM tasks 15 | INNER JOIN projects 16 | ON tasks.project = projects.id 17 | INNER JOIN users AS project_manager 18 | ON projects.project_manager = project_manager.id 19 | INNER JOIN users AS assignee 20 | ON tasks.assignee = assignee.id; 21 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.5.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.5.sql 2 | -- Examples for the usage of the correlation name in the column list 3 | 4 | SELECT tab.table_name, --Column TABLE_NAME is ambigous! 5 | col.column_name 6 | FROM m_cs_tables AS tab 7 | INNER JOIN m_cs_columns AS col 8 | ON tab.table_name = col.table_name; 9 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.50.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.50.sql 2 | -- Example for the usage of the MAP_MERGE operator 3 | 4 | --Creation of a table with tree time intervals: 5 | CREATE TABLE intervals (id INT, from_date date,to_date date); 6 | INSERT INTO intervals VALUES(1, '2017-01-01', '2017-01-05'); 7 | INSERT INTO intervals VALUES(2, '2017-05-01', '2017-05-05'); 8 | INSERT INTO intervals VALUES(3, '2017-05-08', '2017-05-09'); 9 | 10 | -- Creation of a function, that returns all dates within a 11 | -- time interval: 12 | CREATE FUNCTION udf_days(iv_id INT, 13 | iv_from_date date, 14 | iv_to_date date) 15 | RETURNS TABLE (id INT, datum date) 16 | AS BEGIN 17 | RETURN SELECT :iv_id AS id, 18 | GENERATED_PERIOD_START AS datum 19 | FROM SERIES_GENERATE_DATE( 20 | INCREMENT_BY => 'INTERVAL 1 DAY', 21 | MIN_VALUE => :iv_from_date, 22 | MAX_VALUE => ADD_DAYS(:iv_to_date,1)); 23 | END; 24 | 25 | --Execution of MAP_MERGE in an anonymous block: 26 | DO BEGIN 27 | lt_d = SELECT * FROM intervals; 28 | lt_datum = MAP_MERGE( :lt_d, udf_days(:lt_d.id, 29 | :lt_d.from_date, 30 | :lt_d.to_date) ); 31 | SELECT * FROM :lt_datum; 32 | END; 33 | --Clean up of the created objects 34 | DROP TABLE intervals; 35 | DROP FUNCTION udf_days; 36 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.6.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.6.sql 2 | -- Example for * in the field list 3 | 4 | SELECT t1.* , 5 | t2.column1 6 | FROM table1 AS t1 7 | JOIN table2 AS t2 8 | ON t1.key = t2.key; 9 | -------------------------------------------------------------------------------- /Listings/Chapter 3/EN_Listing 3.7.sql: -------------------------------------------------------------------------------- 1 | -- Listing 3.7.sql 2 | -- Operator expressions in the field list of the SELECT-statement 3 | 4 | SELECT id || ' - ' || title AS Aufgabe, 5 | planed_effort, 6 | effort, 7 | round(effort / planed_effort * 100, 0) 8 | || ' %' AS used_time, 9 | completed || ' %' AS completed 10 | FROM tasks; 11 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.1.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.1.sql 2 | -- Example for the handling of data type VARCHAR 3 | 4 | CREATE TABLE tab1 ( 5 | row_nr INT, 6 | col_alphanum ALPHANUM(4), 7 | col_varchar VARCHAR(4), 8 | col_nvarchar NVARCHAR(4) 9 | ); 10 | 11 | INSERT INTO tab1 VALUES ( 1,'碼' , '碼' , '碼' ); 12 | INSERT INTO tab1 VALUES ( 2,'碼碼' , '碼碼', '碼碼' ); 13 | INSERT INTO tab1 VALUES ( 3,'abcd' , 'abcd', 'abcd' ); 14 | INSERT INTO tab1 VALUES ( 4,'Jörg' , 'Jörg', 'Jörg' ); 15 | INSERT INTO tab1 VALUES ( 5,'öö' , 'öö' , 'öö' ); 16 | 17 | SELECT row_nr, 18 | col_alphanum, 19 | col_varchar, 20 | col_nvarchar, 21 | TO_NVARCHAR(col_varchar) AS decoded 22 | FROM tab1 ; 23 | 24 | DROP TABLE tab1; 25 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.10.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.10.sql 2 | -- Example for extracting E-Mail addresses from a log table 3 | 4 | CREATE TABLE logtable (line nvarchar(100)) ; 5 | INSERT INTO logtable VALUES 6 | ('Missing authorizations for elbert@brandeis.de') ; 7 | INSERT INTO logtable VALUES 8 | ('Login failed: sibrylle@tiergarten-ma.com.') ; 9 | INSERT INTO logtable VALUES 10 | ('User ele.fant@tiergarten-ma.de has been logged in.') ; 11 | INSERT INTO logtable VALUES 12 | ('Server restarted.') ; 13 | 14 | SELECT SUBSTR_REGEXPR( 15 | '\b([A-Z0-9._%+-]+)@([A-Z0-9.-]+\.[A-Z]{2,})\b' 16 | FLAG 'i' 17 | IN line 18 | GROUP 1 ) AS name, 19 | SUBSTR_REGEXPR( 20 | '\b([A-Z0-9._%+-]+)@([A-Z0-9.-]+\.[A-Z]{2,})\b' 21 | FLAG 'i' 22 | IN line 23 | GROUP 2 ) AS host, 24 | SUBSTR_REGEXPR( 25 | '\b([A-Z0-9._%+-]+)@([A-Z0-9.-]+\.[A-Z]{2,})\b' 26 | FLAG 'i' 27 | IN line ) AS email, 28 | line 29 | FROM logtable; 30 | DROP TABLE logtable; 31 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.14.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.14.sql 2 | -- Example of searching and replacing with regular expressions 3 | 4 | CREATE TABLE employees (namen NVARCHAR(60)); 5 | 6 | INSERT INTO employees VALUES ('Joerg Brandeis'); 7 | INSERT INTO employees VALUES ('Peter Mueller'); 8 | INSERT INTO employees VALUES ('Michael Maier'); 9 | INSERT INTO employees VALUES ('Superman'); 10 | 11 | SELECT REPLACE_REGEXPR( 12 | '([[:graph:]]+)[[:blank:]]+([[:graph:]]+)' IN namen 13 | WITH 'Lastname: \2 Firstname: \1') 14 | FROM employees; 15 | 16 | DROP TABLE employees; 17 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.15.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.15.sql 2 | -- Example for the PAD functions 3 | 4 | SELECT 'LPAD(''ABC'',8,''begin'')' AS "Function", 5 | LPAD('ABC',8,'begin') AS "Result" 6 | FROM dummy 7 | UNION 8 | SELECT 'LPAD(''123'',8,''0'')' AS "Function", 9 | LPAD('123',8,'0') AS "Result" 10 | FROM dummy 11 | UNION 12 | SELECT 'RPAD(''ABC'',8,''end'')' AS "Function", 13 | RPAD('ABC',8,'end') AS "Result" 14 | FROM dummy; 15 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.16.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.16.sql 2 | -- Example of the TRIM Functions 3 | 4 | SELECT 5 | TRIM(both 'HIA' FROM 'ABCDEFGHI') AS trim_both , 6 | TRIM(leading 'HIA' FROM 'ABCDEFGHI') AS trim_leading , 7 | TRIM(trailing 'HIA' FROM 'ABCDEFGHI') AS trim_trailing, 8 | LTRIM('ABCDEFGHI','HIA') AS "LTRIM()" , 9 | RTRIM('ABCDEFGHI','HIA') AS "RTRIM()" 10 | FROM dummy; 11 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.18.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.18.sql 2 | -- Example for the SQL-Function HAMMING_DISTANCE() 3 | 4 | SELECT * 5 | FROM users 6 | WHERE HAMMING_DISTANCE(firstname, 'Mandy') BETWEEN 0 and 1; 7 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.19.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.19.sql 2 | -- Searching with regular expressions 3 | 4 | SELECT * 5 | FROM users 6 | WHERE lastname LIKE_REGEXPR 'M(a|e)(i|y)(a|er)'; 7 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.2.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.2.sql 2 | -- Example for the behaviour of data type ALPHANUM 3 | 4 | CREATE TABLE strings ( 5 | row_nr INT, 6 | col_alphanum ALPHANUM(4) ); 7 | 8 | INSERT INTO strings VALUES ( 1,'12'); 9 | INSERT INTO strings VALUES ( 2,'012'); 10 | INSERT INTO strings VALUES ( 3,'0012'); 11 | INSERT INTO strings VALUES ( 4,'2'); 12 | INSERT INTO strings VALUES ( 5,'20'); 13 | INSERT INTO strings VALUES ( 6,'2a'); 14 | INSERT INTO strings VALUES ( 7,'a2'); 15 | 16 | SELECT * 17 | FROM strings 18 | ORDER BY col_alphanum; 19 | 20 | DROP TABLE strings; 21 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.20.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.20.sql 2 | -- Conversion of characters to ASCII or Unicode and vice versa 3 | 4 | SELECT ascii('A') AS char2ascii , 5 | char(65) AS asci2char , 6 | unicode('碼') AS nchar2unicode, 7 | nchar('30908') AS unicode2nchar 8 | FROM dummy; 9 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.21.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.21.sql 2 | -- Output of a date as data type DATE and VARCHAR 3 | 4 | CREATE TABLE date_values(line INT,date_val DATE) ; 5 | INSERT INTO date_values VALUES(1,'1.12.2017') ; 6 | INSERT INTO date_values VALUES(2,'2017.12.02') ; 7 | SELECT line, 8 | date_val , 9 | to_varchar(date_val) as as_char 10 | FROM date_values; 11 | DROP TABLE date_values; 12 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.22.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.22.sql 2 | -- Generation and display of the empty date 3 | 4 | CREATE TABLE date_values(line INT,date_val DATE) ; 5 | INSERT INTO date_values VALUES(1,'0') ; 6 | INSERT INTO date_values VALUES(2,'') ; 7 | INSERT INTO date_values VALUES(3,'0000-00-00') ; 8 | INSERT INTO date_values VALUES(4,'00000000') ;--ABAP 9 | INSERT INTO date_values VALUES(5,'0001-01-01') ; 10 | SELECT line, 11 | date_val, 12 | to_varchar(date_val) as as_char, 13 | days_between(date_val, '00001-01-10')as Delta 14 | FROM date_values; 15 | DROP TABLE date_values; 16 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.23.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.23.sql 2 | -- Various date formats 3 | 4 | CREATE TABLE dates ( datum DATE ) ; 5 | 6 | INSERT INTO dates VALUES('1.12.2017') ; 7 | INSERT INTO dates VALUES('2017.12.01') ; 8 | INSERT INTO dates VALUES('20171201') ; 9 | INSERT INTO dates VALUES('2017/12/1') ; 10 | 11 | SELECT * FROM dates; 12 | 13 | DROP TABLE dates; 14 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.24.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.24.sql 2 | -- Example for formatting date fields 3 | 4 | CREATE TABLE tab_format ( format VARCHAR(10), 5 | description nvarchar(40) ) ; 6 | 7 | INSERT INTO tab_format VALUES('YY', 8 | 'Year 2 digits') ; 9 | INSERT INTO tab_format VALUES('YYYY', 10 | 'Year 4 digits') ; 11 | INSERT INTO tab_format VALUES('MM', 12 | 'Month, 2 digits') ; 13 | INSERT INTO tab_format VALUES('DD', 14 | 'Day of the month') ; 15 | INSERT INTO tab_format VALUES('Q', 16 | 'Quarter') ; 17 | INSERT INTO tab_format VALUES('WW', 18 | 'Calendar week') ; 19 | INSERT INTO tab_format VALUES('RM', 20 | 'Month in roman spelling') ; 21 | INSERT INTO tab_format VALUES('MON', 22 | '3-digit abbreviation of the month') ; 23 | INSERT INTO tab_format VALUES('MONTH', 24 | 'Name of the month (english)') ; 25 | INSERT INTO tab_format VALUES('DDD', 26 | 'Day of the year') ; 27 | INSERT INTO tab_format VALUES('YYYY=MM=DD', 28 | 'Example for an individual pattern') ; 29 | SELECT 30 | format, 31 | to_varchar( to_dats( '27.12.2018'), 32 | format ) AS "Example", 33 | description 34 | FROM tab_format ; 35 | DROP TABLE tab_format ; 36 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.25.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.25.sql 2 | -- Error when calculating with DATS fields 3 | 4 | CREATE TABLE abap_dats(datum VARCHAR(8)); 5 | INSERT INTO abap_dats VALUES ('20180601'); 6 | INSERT INTO abap_dats VALUES ('20180618'); 7 | INSERT INTO abap_dats VALUES ('20180101'); 8 | INSERT INTO abap_dats VALUES ('20170601'); 9 | 10 | SELECT datum AS dats, 11 | TO_DATE(datum) AS date, 12 | datum - '20180601' as delta 13 | FROM abap_dats; 14 | 15 | DROP TABLE abap_dats; 16 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.26.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.26.sql 2 | -- Conversion from TIME to string 3 | 4 | CREATE TABLE tab_format ( format VARCHAR(10), 5 | description nvarchar(40) ) ; 6 | 7 | INSERT INTO tab_format VALUES('HH24', 8 | '24 hours format') ; 9 | INSERT INTO tab_format VALUES('HH', 10 | '12 hours format') ; 11 | INSERT INTO tab_format VALUES('HH12', 12 | '12 hours format') ; 13 | INSERT INTO tab_format VALUES('AM', 14 | 'AM or PM') ; 15 | INSERT INTO tab_format VALUES('PM', 16 | 'AM or PM') ; 17 | INSERT INTO tab_format VALUES('MI', 18 | 'Minutes') ; 19 | INSERT INTO tab_format VALUES('SS', 20 | 'Seconds') ; 21 | INSERT INTO tab_format VALUES('SSSSS', 22 | 'Seconds since midnight') ; 23 | SELECT 24 | format, 25 | to_varchar( to_time( '09:50:13'), 26 | format ) AS "Example 09:50:13", 27 | to_varchar( to_time( '13:07:38'), 28 | format ) AS "Example 13:07:38", 29 | description 30 | FROM tab_format ; 31 | DROP TABLE tab_format ; 32 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.27.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.27.sql 2 | -- Diferences between the SQL-functions ADD_MONTHS() and ADD_MONTHS_LAST() 3 | 4 | SELECT ADD_MONTHS_LAST('2017-02-28', 1) FROM DUMMY; 5 | --> 31.03.2017 6 | SELECT ADD_MONTHS('2017-02-28', 1) FROM DUMMY; 7 | --> 28.03.2017 8 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.28.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.28.sql 2 | -- Splitting a date or a time into its components 3 | 4 | SELECT 5 | 1 AS row, 6 | YEAR(CURRENT_DATE) AS "Year", 7 | MONTH(CURRENT_DATE) AS "Month", 8 | DAYOFMONTH(CURRENT_DATE) AS "Day", 9 | HOUR(CURRENT_TIME) AS "Hour", 10 | MINUTE(CURRENT_TIME) AS "Minute", 11 | SECOND(CURRENT_TIME) AS "Second" 12 | FROM DUMMY 13 | UNION ALL 14 | SELECT 15 | 2 AS row, 16 | EXTRACT(YEAR FROM CURRENT_DATE) AS "Year", 17 | EXTRACT(MONTH FROM CURRENT_DATE) AS "Month", 18 | EXTRACT(DAY FROM CURRENT_DATE) AS "Day", 19 | EXTRACT(hour FROM CURRENT_TIME) AS "Hour", 20 | EXTRACT(minute FROM CURRENT_TIME) AS "Minute", 21 | EXTRACT(second FROM CURRENT_TIME) AS "Second" 22 | FROM dummy; 23 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.29.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.29.sql 2 | -- Determination of the calendar week 3 | 4 | SELECT 5 | WEEK('2017-12-08'), -->50 6 | ISOWEEK('2017-12-08') -->2017-W49 7 | FROM dummy 8 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.3.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.3.sql 2 | -- The length of character strings 3 | 4 | SELECT length('') AS length_space, 5 | length('Peter') AS length_peter, 6 | length('Jörg') AS length_joerg, 7 | length('碼') AS length_china, 8 | length(to_varchar('碼')) AS lenght_china_vc 9 | FROM dummy; 10 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.30.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.30.sql 2 | -- Calculation of the machine running time in hours 3 | 4 | CREATE TABLE runtimes(from_date VARCHAR(8), 5 | from_time VARCHAR(6), 6 | to_date VARCHAR(8), 7 | to_time VARCHAR(6)); 8 | INSERT INTO runtimes VALUES ( '20180101', '060000', 9 | '20180101', '065900' ); 10 | INSERT INTO runtimes VALUES ( '20180101', '060000', 11 | '20180101', '140000' ); 12 | INSERT INTO runtimes VALUES ( '20180101', '060000', 13 | '20180103', '050000' ); 14 | INSERT INTO runtimes VALUES ( '20180101', '060000', 15 | '20180201', '060000' ); 16 | 17 | SELECT FLOOR( 18 | SECONDS_BETWEEN( 19 | TO_SECONDDATE( 20 | TO_DATE(from_date) 21 | ||' '|| 22 | TO_TIME(from_time)), 23 | TO_SECONDDATE( 24 | TO_DATE(to_date) 25 | ||' '|| 26 | TO_TIME(to_time))) 27 | / 60 /*seconds to minutes*/ 28 | / 60 /*minutes to hours*/) 29 | 30 | AS runtime_in_hours 31 | FROM runtimes; 32 | 33 | DROP TABLE runtimes; 34 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.31.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.31.sql 2 | -- Example for a filter on the last four completed weeks 3 | 4 | CREATE TABLE dats_table(calday varchar(8)); 5 | -- The date values must be adjusted accordingly: 6 | INSERT INTO dats_table VALUES (TO_DATS('10.04.2019')); 7 | INSERT INTO dats_table VALUES (TO_DATS('11.04.2019')); 8 | INSERT INTO dats_table VALUES (TO_DATS('13.05.2019')); 9 | INSERT INTO dats_table VALUES (TO_DATS('14.05.2019')); 10 | SELECT * 11 | FROM dats_table 12 | WHERE calday <= TO_DATS(ADD_DAYS(CURRENT_DATE, UMINUS( 13 | WEEKDAY(CURRENT_DATE) + 1))) 14 | AND calday >= TO_DATS(ADD_DAYS(CURRENT_DATE, UMINUS( 15 | WEEKDAY(CURRENT_DATE) + 28))); 16 | DROP TABLE dats_table; 17 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.32.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.32.sql 2 | -- Transferring the date calculation to a function 3 | 4 | SELECT * 5 | FROM dats 6 | WHERE calday <= TO_DATS(UDF_ADD_DAYS_TO_LAST_SUNDAY(0)) 7 | AND calday >= TO_DATS(UDF_ADD_DAYS_TO_LAST_SUNDAY(27)); 8 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.33.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.33.sql 2 | -- Comparison of decimal and binary floating point numbers 3 | 4 | SELECT TO_DOUBLE(1.2)-TO_DOUBLE(0.1) FROM DUMMY; 5 | SELECT TO_SMALLDECIMAL(1.2)-TO_SMALLDECIMAL(0.1) FROM DUMMY; 6 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.34.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.34.sql 2 | -- Basic arithmetic operations in SQL 3 | 4 | CREATE TABLE calc( value1 INTEGER, 5 | value2 INTEGER ) ; 6 | 7 | INSERT INTO calc VALUES(1,1) ; 8 | INSERT INTO calc VALUES(2,0) ; 9 | INSERT INTO calc VALUES(0,2) ; 10 | INSERT INTO calc VALUES(3,2) ; 11 | SELECT 12 | value1-value2 AS difference, 13 | value1+value2 AS sum, 14 | value1*value2 AS product, 15 | CASE 16 | WHEN value2<>0 17 | THEN value1/value2 18 | ELSE 0 19 | END AS division, 20 | CASE 21 | WHEN value2<>0 22 | THEN MOD(value1,value2) 23 | ELSE 0 24 | END AS modulo 25 | FROM calc; 26 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.35.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.35.sql 2 | -- Examples of rounding functions 3 | 4 | CREATE TABLE calc( val double) ; 5 | 6 | INSERT INTO calc VALUES(1) ; 7 | INSERT INTO calc VALUES(1.1) ; 8 | INSERT INTO calc VALUES(-1.1) ; 9 | INSERT INTO calc VALUES(1.499999) ; 10 | INSERT INTO calc VALUES(1.500000) ; 11 | INSERT INTO calc VALUES(-1.499999) ; 12 | INSERT INTO calc VALUES(-1.500000) ; 13 | INSERT INTO calc VALUES(1.749999) ; 14 | INSERT INTO calc VALUES(1.750000) ; 15 | INSERT INTO calc VALUES(175) ; 16 | 17 | SELECT 18 | val, 19 | CEIL(val) AS ceiling, 20 | FLOOR(val) AS floor, 21 | ROUND(val, 0, ROUND_HALF_UP) AS rhu_0, 22 | ROUND(val, 0, ROUND_UP) AS ru_0, 23 | ROUND(val, 1, ROUND_HALF_UP) AS rhu_1, 24 | ROUND(val, 1, ROUND_UP) AS ru_1, 25 | ROUND(val, -1) AS rhu_m1 26 | FROM calc; 27 | 28 | DROP TABLE calc; 29 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.36.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.36.sql 2 | -- Example of quantity conversion to a fixed unit 3 | 4 | CREATE TABLE quantities ( 5 | quantity DECIMAL(15,2), 6 | unit VARCHAR(3) ) ; 7 | INSERT INTO quantities VALUES(1.0,'MG') ; 8 | INSERT INTO quantities VALUES(1.0,'G') ; 9 | INSERT INTO quantities VALUES(1.0,'KG') ; 10 | INSERT INTO quantities VALUES(1.0,'TO') ; 11 | INSERT INTO quantities VALUES(1.0,'XYZ') ; 12 | 13 | SELECT 14 | quantity AS "quantity", 15 | unit AS "unit", 16 | CONVERT_UNIT( 17 | QUANTITY => quantity, 18 | SOURCE_UNIT => unit, 19 | SCHEMA => 'JBRANDEIS', 20 | TARGET_UNIT => 'KG', 21 | ERROR_HANDLING => 'set to null', 22 | CLIENT => '000') 23 | AS "Quantity in Kg", 24 | 'Kg' AS "Kg" 25 | FROM quantities; 26 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.37.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.37.sql 2 | -- Example of a simple currency translation 3 | 4 | CREATE TABLE amounts( 5 | amount DEC(17,2), 6 | currency VARCHAR(3) ) ; 7 | 8 | INSERT INTO amounts VALUES(89.90,'EUR') ; 9 | INSERT INTO amounts VALUES(17.20,'USD') ; 10 | INSERT INTO amounts VALUES(4.54,'GBP') ; 11 | 12 | SELECT 13 | amount AS "Amount", 14 | currency AS "Currency", 15 | CONVERT_CURRENCY( AMOUNT => amount, 16 | SOURCE_UNIT => currency, 17 | SCHEMA => 'JBRANDEIS', 18 | TARGET_UNIT => 'USD', 19 | REFERENCE_DATE => '2013-09-23', 20 | CLIENT => '000') 21 | AS "Amount in USD", 22 | 'USD' AS "USD" 23 | FROM amounts; 24 | 25 | DROP TABLE amounts; 26 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.38.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.38.sql 2 | -- Conversion from ASCII decimal to VARBINARY 3 | 4 | CREATE COLUMN TABLE test_varbin( 5 | ascii_int INT, 6 | ascii_char VARCHAR(1), 7 | ascii_hex VARBINARY(1)) ; 8 | 9 | DO BEGIN 10 | DECLARE i INT; 11 | FOR i IN 33..127 DO 12 | INSERT INTO test_varbin VALUES(:i, 13 | CHAR(:i), 14 | bintonhex(CHAR(:i))) ; 15 | END FOR; 16 | END; 17 | 18 | SELECT ascii_int as "Int", 19 | ascii_char as "Char", 20 | ascii_hex as "Hex" FROM test_varbin; 21 | DROP TABLE test_varbin; 22 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.39.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.39.sql 2 | -- Function for the representation of integers as bits 3 | 4 | CREATE FUNCTION udf_int_as_bit_string(iv_value INT) 5 | RETURNS rv_value VARCHAR(8) 6 | AS BEGIN 7 | DECLARE lv_value INT default :iv_value; 8 | DECLARE lv_mod INT; 9 | rv_value = ''; 10 | 11 | WHILE lv_value > 0 DO 12 | lv_mod = MOD(:lv_value, 2); 13 | IF lv_mod = 1 THEN 14 | rv_value = '1' || :rv_value; 15 | ELSE 16 | rv_value = '0' || :rv_value; 17 | END IF; 18 | lv_value = lv_value / 2; 19 | END WHILE; 20 | rv_value = LPAD(rv_value, 8, '0'); 21 | END; 22 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.4.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.4.sql 2 | -- Concatination of character strings 3 | 4 | CREATE column TABLE tab(col1 nvarchar(10) , 5 | col2 nvarchar(10)) ; 6 | INSERT INTO tab VALUES(' ' , 'A' ) ; 7 | INSERT INTO tab VALUES('A ', ' B') ; 8 | INSERT INTO tab VALUES(' A', 'B ') ; 9 | SELECT '"' || col1 || col2 || '"' AS "|| Operator" , 10 | concat(concat('"' , col1) , 11 | concat(col2, '"')) AS "CONCAT Function" 12 | FROM tab; 13 | DROP TABLE tab; 14 | 15 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.40.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.40.sql 2 | -- Example for bitwise processing of binary data 3 | 4 | CREATE TABLE binval(text NVARCHAR(50), 5 | value int); 6 | INSERT INTO binval VALUES ('Integer 248', 248 ); 7 | INSERT INTO binval VALUES ('Integer 31', 31 ); 8 | INSERT INTO binval VALUES ('XOR(248, 31)', BITXOR(248, 31)); 9 | INSERT INTO binval VALUES ('AND(248, 31)', BITAND(248, 31)); 10 | INSERT INTO binval VALUES ('OR(248, 31)' , BITOR(248, 31)); 11 | 12 | SELECT text, 13 | udf_int_as_bit_string(value) 14 | FROM binval; 15 | 16 | DROP TABLE binval; 17 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.5.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/96b3425219d6cafbec7dd3d81f79120b35a674e2/Listings/Chapter 4/EN_Listing 4.5.sql -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.6.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.6.sql 2 | -- Decomposition of character strings with position information 3 | 4 | SELECT LEFT('ABCDEFGHI',3) AS left_part, -->'ABC' 5 | SUBSTRING('ABCDEFGHI',4,3) AS middle_part, -->'DEF' 6 | RIGHT('ABCDEFGHI',3) AS right_part -->'GHI' 7 | FROM 8 | DUMMY; 9 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.7.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.7.sql 2 | -- String decomposition with SUBSTR_BEFORE and SUBSTR_AFTER 3 | 4 | SELECT 5 | substr_before('String decomposition','de') AS before_de , 6 | substr_after('String decomposition','de') AS after_de, 7 | substr_after('String decomposition','') AS everything , 8 | substr_after('String decomposition','ABC') AS nothing 9 | FROM 10 | DUMMY; 11 | -------------------------------------------------------------------------------- /Listings/Chapter 4/EN_Listing 4.9.sql: -------------------------------------------------------------------------------- 1 | -- Listing 4.9.sql 2 | -- Simple string decomposition with regular expressions 3 | 4 | CREATE TABLE companies( name NVARCHAR(30) ) ; 5 | INSERT INTO companies VALUES('Broadcom Ltd.') ; 6 | INSERT INTO companies VALUES('SAP SE') ; 7 | INSERT INTO companies VALUES('Shire PLC') ; 8 | INSERT INTO companies VALUES('Siemens AG') ; 9 | SELECT SUBSTR_REGEXPR('PLC|Ltd.|SE|AG' IN name) AS legalform, 10 | name 11 | FROM companies; 12 | DROP TABLE companies; 13 | -------------------------------------------------------------------------------- /Listings/Chapter 5/EN_Listing 5.1.sql: -------------------------------------------------------------------------------- 1 | -- Listing 5.1.sql 2 | -- Tables for the examples in this chapter 3 | 4 | CREATE TABLE table_1( 5 | key1 INT DEFAULT 5, 6 | key2 INT, 7 | value1 NVARCHAR(200), 8 | PRIMARY KEY ( 9 | key1, 10 | key2 ) 11 | ); 12 | CREATE TABLE table_2( 13 | key1 INT PRIMARY KEY, 14 | value1 NVARCHAR(200), 15 | value2 NVARCHAR(200) 16 | ); 17 | -------------------------------------------------------------------------------- /Listings/Chapter 5/EN_Listing 5.11.sql: -------------------------------------------------------------------------------- 1 | -- Listing 5.11.sql 2 | -- Example for the MERGE INTO statement 3 | 4 | DELETE FROM table_1; 5 | DELETE FROM table_2; 6 | INSERT INTO table_2 VALUES(1, '', 'First row'); 7 | INSERT INTO table_2 VALUES(2, '', 'Second row'); 8 | INSERT INTO table_2 VALUES(3, '', 'Third row'); 9 | INSERT INTO table_2 VALUES(4, '', 'Forth row'); 10 | 11 | MERGE INTO table_1 12 | USING table_2 13 | ON (table_1.key1 = table_2.key1) 14 | WHEN MATCHED THEN 15 | UPDATE SET table_1.key1 = table_2.key1, 16 | table_1.key2 = 1, 17 | table_1.value1 = 'UPDATE: ' 18 | || table_1.value1 19 | WHEN NOT MATCHED THEN 20 | INSERT VALUES( table_2.key1, 21 | 1, 22 | 'INSERT: ' || table_2.value2); 23 | 24 | MERGE INTO table_1 25 | USING table_2 26 | ON (table_1.key1 = table_2.key1) 27 | WHEN MATCHED THEN 28 | UPDATE SET table_1.key1 = table_2.key1, 29 | table_1.key2 = 1, 30 | table_1.value1 = 'UPDATE: ' 31 | || table_1.value1 32 | WHEN NOT MATCHED THEN 33 | INSERT VALUES( table_2.key1, 34 | 1, 35 | 'INSERT: ' || table_2.value2); 36 | 37 | SELECT * FROM table_1; 38 | -------------------------------------------------------------------------------- /Listings/Chapter 5/EN_Listing 5.12.sql: -------------------------------------------------------------------------------- 1 | -- Listing 5.12.sql 2 | -- MERGE INTO with local table variable 3 | 4 | DO BEGIN 5 | lt_tmp = select * from table_2; 6 | MERGE INTO table_1 7 | USING :lt_tmp as t2 8 | ON (table_1.key1 = t2.key1) 9 | WHEN MATCHED THEN 10 | UPDATE SET table_1.key1 = t2.key1, 11 | table_1.key2 = 1, 12 | table_1.value1 = 'UPDATE: ' 13 | || table_1.value1 14 | WHEN NOT MATCHED THEN 15 | INSERT VALUES( t2.key1, 16 | 1, 17 | 'INSERT: ' || t2.value2); 18 | END; 19 | -------------------------------------------------------------------------------- /Listings/Chapter 5/EN_Listing 5.2.sql: -------------------------------------------------------------------------------- 1 | -- Listing 5.2.sql 2 | -- Example of inserting with column sequence 3 | 4 | INSERT INTO table_1 (key2, value1) 5 | VALUES ( 2, 'Defaultvalue'); 6 | INSERT INTO table_1 (value1, key1, key2) 7 | VALUES ('Changed columns', 2, 3); 8 | -------------------------------------------------------------------------------- /Listings/Chapter 5/EN_Listing 5.3.sql: -------------------------------------------------------------------------------- 1 | -- Listing 5.3.sql 2 | -- Example of an INSERT statement with multiple data records 3 | 4 | INSERT INTO table_2 5 | SELECT key1 + key2 * 100, 6 | value1, 7 | 'Insert from a query' 8 | FROM table_1; 9 | -------------------------------------------------------------------------------- /Listings/Chapter 5/EN_Listing 5.5.sql: -------------------------------------------------------------------------------- 1 | -- Listing 5.5.sql 2 | -- INSERT with query to a local table variable and changed column order 3 | 4 | DO BEGIN 5 | lt_tmp = SELECT key1 + 10 as key1, 6 | key2, 7 | 'Copy: '|| value1 as value1 8 | FROM table_1; 9 | 10 | INSERT INTO table_1 11 | (value1, key1, key2) 12 | SELECT value1, 13 | key1, 14 | key2 15 | FROM :lt_tmp; 16 | END; 17 | -------------------------------------------------------------------------------- /Listings/Chapter 5/EN_Listing 5.6.sql: -------------------------------------------------------------------------------- 1 | -- Listing 5.6.sql 2 | -- Example of a simple UPDATE Statement 3 | 4 | UPDATE table_2 5 | SET value1 = 'Updated', 6 | value2 = 'Line ' || key1 7 | WHERE key1 < 300; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 5/EN_Listing 5.7.sql: -------------------------------------------------------------------------------- 1 | -- Listing 5.7.sql 2 | -- Example of an UPDATE statement with reference to another table 3 | 4 | UPDATE table_2 as t2 --or: UPDATE t2 5 | SET t2.value1 = t1.value1 6 | FROM table_2 as t2, 7 | table_1 as t1 8 | WHERE t2.key1 = t1.key1 + t1.key2 * 100; 9 | -------------------------------------------------------------------------------- /Listings/Chapter 5/EN_Listing 5.8.sql: -------------------------------------------------------------------------------- 1 | -- Listing 5.8.sql 2 | -- Example of inserting and updating using the primary key 3 | 4 | DELETE FROM table_1; 5 | DELETE FROM table_2; 6 | --Insert single records 7 | UPSERT table_1 VALUES(1, 1, 'Inserted with UPSERT') 8 | WITH PRIMARY KEY; 9 | UPSERT table_1 VALUES(1, 2, 'Inserted with UPSERT') 10 | WITH PRIMARY KEY; 11 | UPSERT table_1 VALUES(1, 3, 'Inserted with UPSERT') 12 | WITH PRIMARY KEY; 13 | --Update a record using the primary key 14 | UPSERT table_1 VALUES(1, 2, 'Changed with UPSERT') 15 | WITH PRIMARY KEY; 16 | 17 | SELECT * FROM table_1; 18 | -------------------------------------------------------------------------------- /Listings/Chapter 5/EN_Listing 5.9.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/96b3425219d6cafbec7dd3d81f79120b35a674e2/Listings/Chapter 5/EN_Listing 5.9.sql -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.10.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.10.sql 2 | -- Example for inserting a table variable line by line with INSERT 3 | 4 | DO (OUT rt_result TABLE( id INT, 5 | text1 NVARCHAR(50), 6 | text2 NVARCHAR(50))=>? ) 7 | BEGIN 8 | DECLARE lv_index INT; 9 | 10 | FOR lv_index IN 1..5 11 | DO 12 | -- Inserting all columns at position 1 13 | :rt_result.INSERT((lv_index, 14 | 'Insert '||lv_index, '') 15 | , 1); 16 | END FOR; 17 | 18 | FOR lv_index IN 1..5 19 | DO 20 | -- Append to the table, only for two columns 21 | :rt_result.(id, text2).INSERT((lv_index, 22 | 'Append '||lv_index)); 23 | END FOR; 24 | END; 25 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.11.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.11.sql 2 | -- Tablewise insertion with the INSERT operation 3 | 4 | DO (OUT ot_result TABLE( id INT, 5 | text1 NVARCHAR(50), 6 | text2 NVARCHAR(50))=>? ) 7 | BEGIN 8 | DECLARE lv_index INT; 9 | DECLARE lt_tmp TABLE (column1 INT, 10 | column2 NVARCHAR(50) ); 11 | 12 | -- Build table LT_TMP line by line 13 | :lt_tmp.INSERT((1, 'TMP_1')); 14 | :lt_tmp.INSERT((2, 'TMP_2')); 15 | 16 | -- Build table RT_RESULT line by line 17 | :ot_result.INSERT((1, 'First record ', 'A')); 18 | :ot_result.INSERT((2, 'Second record', 'B')); 19 | :ot_result.INSERT((3, 'Third record', 'C')); 20 | 21 | -- insert table LT_TMP into RT_RESULT at index 2 22 | :ot_result.(id, text1).INSERT(:lt_tmp, 2); 23 | 24 | END; 25 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.12.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.12.sql 2 | -- Updating a table variable line by line with UPDATE and index-based access 3 | 4 | DO (OUT ot_result TABLE(text NVARCHAR(100))=>?) 5 | BEGIN 6 | DECLARE indx integer; 7 | 8 | -- Build the table line by line 9 | :ot_result.INSERT(('Insert 1'), 1); 10 | :ot_result.INSERT(('Insert 2'), 2); 11 | :ot_result.INSERT(('Insert 3'), 3); 12 | 13 | -- UPDATE of the lines 2 and 4 14 | :ot_result.UPDATE(('Update 2'),2); 15 | :ot_result.UPDATE(('Update 4'),4); 16 | 17 | -- Update with index-based access 18 | ot_result[6] = ('Insert 6'); 19 | END; 20 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.13.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.13.sql 2 | -- Examples of the different variants of deleting rows from a table variable 3 | 4 | DO (OUT ot_result TABLE(text NVARCHAR(100))=>?) 5 | BEGIN 6 | DECLARE lv_index INT; 7 | DECLARE lv_del INT ARRAY = ARRAY(1, 3); 8 | 9 | -- Build a table with the rows 1 t0 10 10 | FOR lv_index IN 1..10 DO 11 | :ot_result.INSERT(('Line '||lv_index), lv_index); 12 | END FOR; 13 | 14 | -- Deletion of the line at index 9 15 | :ot_result.DELETE(9); 16 | 17 | -- Deletion of the lines 5 to 7 18 | :ot_result.DELETE(5..7); 19 | 20 | -- Deletion of the lines from the array LV_DEL 21 | :ot_result.DELETE(:lv_del); 22 | 23 | END; 24 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.15.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.15.sql 2 | -- Search in tables with the SEARCH operator 3 | 4 | DO (OUT ot_result TABLE( id INT, 5 | status INT, 6 | assignee INT, 7 | title NVARCHAR(50))=>? ) 8 | BEGIN 9 | DECLARE lv_index INT = 0; 10 | 11 | ot_result = SELECT id, 12 | status, 13 | assignee, 14 | title 15 | FROM tasks 16 | ORDER BY id; 17 | 18 | -- Usage of the SEARCH operator 19 | lv_index = :ot_result.SEARCH((status, assignee), 20 | (3,3)); 21 | 22 | :ot_result.DELETE(lv_index); 23 | 24 | -- Usage of the SEARCH operator in the DELETE operator 25 | :ot_result.DELETE(:ot_result.SEARCH((status, assignee), 26 | (3,3))); 27 | 28 | END; 29 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.16.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.16.sql 2 | -- Use of session variables 3 | 4 | DO BEGIN 5 | SET 'TESTVARIABLE' = 'TESTVALUE'; 6 | SELECT session_context( 'TESTVARIABLE' ) FROM dummy; 7 | END; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.17.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.17.sql 2 | -- Example of a global temporary table 3 | 4 | CREATE GLOBAL TEMPORARY TABLE test_gtt (id INT, 5 | text NVARCHAR(40)); 6 | INSERT INTO test_gtt ( SELECT id, title FROM tasks); 7 | SELECT * FROM test_gtt; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.18.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.18.sql 2 | -- Example of a local temporary table 3 | 4 | CREATE LOCAL TEMPORARY TABLE #test_ltt (id INT, 5 | text NVARCHAR(40)); 6 | INSERT INTO #test_ltt ( SELECT id, title FROM tasks); 7 | SELECT * FROM #test_ltt; 8 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.2.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.2.sql 2 | -- Missing initialization of a variable 3 | 4 | DO BEGIN 5 | DECLARE lv_sum INT ; 6 | DECLARE lv_indx INT; 7 | 8 | FOR lv_indx IN 1..10 DO 9 | lv_sum = :lv_sum + 10; 10 | END FOR; 11 | 12 | SELECT :lv_sum FROM dummy; 13 | 14 | END ; 15 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.20.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/96b3425219d6cafbec7dd3d81f79120b35a674e2/Listings/Chapter 6/EN_Listing 6.20.sql -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.21.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.21.sql 2 | -- Function UDF_SORT_2 for sorting two numbers 3 | 4 | CREATE FUNCTION udf_sort_2(iv_value1 INT, 5 | iv_value2 INT ) 6 | RETURNS rv_lower INT, 7 | rv_higher INT 8 | AS BEGIN 9 | IF iv_value1 >= iv_value2 THEN 10 | rv_lower = iv_value2; 11 | rv_higher = iv_value1; 12 | ELSE 13 | rv_lower = iv_value1; 14 | rv_higher = iv_value2; 15 | END IF; 16 | END; 17 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.22.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.22.sql 2 | -- Function UDF_SORT_3 for sorting three numbers 3 | 4 | CREATE FUNCTION udf_sort_3(iv_value1 INT, 5 | iv_value2 INT, 6 | iv_value3 INT ) 7 | RETURNS rv_lower INT, 8 | rv_middle INT, 9 | rv_higher INT 10 | AS BEGIN 11 | --Initial assignment (probably wrong) 12 | rv_lower = :iv_value1; 13 | rv_middle = :iv_value2; 14 | rv_higher = :iv_value3; 15 | 16 | --Exchange until sorting is correct 17 | (rv_lower, rv_middle) = udf_sort_2(rv_lower, rv_middle); 18 | (rv_lower, rv_higher) = udf_sort_2(rv_lower, rv_higher); 19 | (rv_middle, rv_higher) = udf_sort_2(rv_middle, rv_higher); 20 | END; 21 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.23.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.23.sql 2 | -- Anonymous block for testing the function UDF_SORT_3 3 | 4 | DO (OUT ov_lower INT=>?, 5 | OUT ov_middle INT=>?, 6 | OUT ov_higher INT=>?) 7 | BEGIN 8 | (ov_lower, ov_middle, ov_higher) = udf_sort_3(1,11,9); 9 | END; 10 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.24.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.24.sql 2 | -- Example of a FOR loop 3 | 4 | DO BEGIN 5 | DECLARE lv_sum INT = 0; 6 | DECLARE lv_indx INT; 7 | FOR lv_indx IN 1..10 DO 8 | DECLARE lv_tmp INT = lv_sum; 9 | lv_tmp = :lv_tmp + 10; 10 | lv_sum = lv_tmp; 11 | END FOR; 12 | 13 | SELECT :lv_indx, :lv_sum FROM dummy; 14 | END; 15 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.25.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.25.sql 2 | -- Example of a WHILE Loop 3 | 4 | CREATE FUNCTION udf_factorial ( IN iv_value INT) 5 | RETURNS rv_result INT 6 | AS BEGIN 7 | DECLARE lv_counter INT = 1; 8 | rv_result = 1; 9 | WHILE lv_counter <= iv_value DO 10 | rv_result = rv_result * lv_counter; 11 | lv_counter = lv_counter + 1; 12 | END WHILE; 13 | END; 14 | 15 | SELECT udf_factorial( 10 ) FROM dummy; 16 | 17 | DROP FUNCTION udf_factorial; 18 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.26.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.26.sql 2 | -- Example for calcluation the greatest common divisor 3 | 4 | CREATE FUNCTION udf_gcd(iv_number1 INT, 5 | iv_number2 INT ) 6 | RETURNS rv_ggt INT 7 | AS BEGIN 8 | DECLARE lv_number1 INT DEFAULT :iv_number1; 9 | DECLARE lv_number2 INT DEFAULT :iv_number2; 10 | DECLARE lv_cnt INT DEFAULT 0; 11 | 12 | WHILE lv_number1 <> lv_number2 DO 13 | --FOR lv_cnt IN 0..100 DO 14 | DECLARE lv_lower INT DEFAULT 0; 15 | DECLARE lv_higher INT DEFAULT 0; 16 | --IF lv_number1 = lv_number2 THEN BREAK; 17 | --END IF; 18 | 19 | (lv_lower, lv_higher) = udf_sort_2(:lv_number1, 20 | :lv_number2); 21 | lv_number1 = :lv_higher - :lv_lower; 22 | lv_number2 = :lv_lower; 23 | END WHILE; 24 | --END FOR; 25 | rv_ggt = :lv_number1; 26 | END; 27 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.28.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.28.sql 2 | -- Example of a FOR loop over a cursor with parameter 3 | 4 | CREATE PROCEDURE close_projects 5 | AS 6 | BEGIN 7 | DECLARE CURSOR lc_projects (iv_status INT) 8 | FOR SELECT id 9 | FROM projects 10 | WHERE status = :iv_status; 11 | 12 | FOR ls_projects AS lc_projects(5) --Status = Closed 13 | DO CALL close_tasks(ls_projects.id); 14 | END FOR; 15 | END; 16 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.29.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.29.sql 2 | -- Example for the use of a cursor 3 | 4 | DO ( OUT ov_all_titles NVARCHAR(900) => ?) 5 | BEGIN 6 | lt_tasks = SELECT TOP 10 title FROM tasks; 7 | ov_all_titles = ''; 8 | 9 | BEGIN 10 | DECLARE CURSOR lc_tasks 11 | FOR SELECT title FROM :lt_tasks; 12 | 13 | DECLARE lv_indx INT; 14 | DECLARE lv_title NVARCHAR(40); 15 | 16 | OPEN lc_tasks; 17 | WHILE 1 <> 2 DO 18 | FETCH lc_tasks INTO lv_title; 19 | IF lc_tasks::NOTFOUND THEN 20 | BREAK; 21 | END IF; 22 | ov_all_titles = ov_all_titles || ' - ' || lv_title; 23 | END WHILE; 24 | CLOSE lc_tasks; 25 | END; 26 | END; 27 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.3.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.3.sql 2 | -- Example for assigning values to local scalar variables 3 | 4 | CREATE FUNCTION udf_statistic 5 | RETURNS rv_projects INT, 6 | rv_assignee INT AS 7 | BEGIN 8 | --Assigning variables using a SELECT INTO statement 9 | SELECT 10 | COUNT( DISTINCT project), 11 | COUNT( DISTINCT assignee) 12 | INTO rv_projects, 13 | rv_assignee 14 | FROM 15 | tasks; 16 | END; 17 | 18 | DO BEGIN 19 | DECLARE lv_projects INTEGER; 20 | DECLARE lv_assignee INTEGER; 21 | DECLARE lv_div DEC; 22 | 23 | -- Assignment of multiple variables by scalar UDF 24 | (lv_projects, lv_assignee) = udf_statistic( ); 25 | 26 | -- Assignment by an expression 27 | lv_div = :lv_assignee / :lv_projects; 28 | 29 | SELECT 30 | lv_projects AS projects, 31 | lv_assignee AS assignee, 32 | lv_div AS assignee_pro_project 33 | FROM 34 | dummy; 35 | END ; 36 | DROP FUNCTION udf_statistic; 37 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.30.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/96b3425219d6cafbec7dd3d81f79120b35a674e2/Listings/Chapter 6/EN_Listing 6.30.sql -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.31.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.31.sql 2 | -- ARRAYs in SQLScript sourcecode 3 | 4 | DO BEGIN 5 | DECLARE i INT; 6 | DECLARE demo VARCHAR(20) ARRAY; 7 | 8 | -- Insert 10 elements in the ARRAY 9 | FOR i IN 1..10 DO 10 | demo[:i] = concat ('Value ', :i); 11 | END FOR; 12 | 13 | SELECT :demo[10] FROM dummy; 14 | 15 | -- Remove the last 5 elements 16 | demo = TRIM_ARRAY( :demo, 5 ); 17 | SELECT :demo[1], 18 | :demo[5], 19 | :demo[10] 20 | FROM dummy; 21 | 22 | -- Insert an element at position 20 23 | demo[20] = 'Last Element'; 24 | SELECT :demo[5], 25 | :demo[10], 26 | :demo[20] 27 | FROM dummy; 28 | END; 29 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.32.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.32.sql 2 | -- Conversion of ARRAYs into tables with UNNEST() 3 | 4 | DO BEGIN 5 | DECLARE animals VARCHAR(10) ARRAY = ARRAY('Dog', 'Cat', 6 | 'Mouse'); 7 | DECLARE colors VARCHAR(10) ARRAY = ARRAY('red', 'yellow', 8 | 'blue', 'orange', 'green', 'purple'); 9 | 10 | table = UNNEST(:animals, :colors) 11 | WITH ORDINALITY AS ( 12 | "Animal", 13 | "Color", 14 | "Nr" 15 | ); 16 | 17 | SELECT * 18 | FROM :table; 19 | END; 20 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.33.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.33.sql 2 | -- Conversion of a table column into an array and query of the cardinality 3 | 4 | DO BEGIN 5 | DECLARE lv_cardinality INT; 6 | DECLARE la_assignee INT ARRAY; 7 | 8 | lt_tasks = SELECT DISTINCT assignee FROM tasks; 9 | la_assignee = ARRAY_AGG(:lt_tasks.assignee); 10 | lv_cardinality = CARDINALITY(:la_assignee); 11 | SELECT :lv_cardinality 12 | FROM DUMMY; 13 | END; 14 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.34.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.34.sql 2 | -- The bubble-sort algorithm in SQLScript 3 | 4 | --Create tabletype TT_VALUE for the parameters 5 | CREATE TYPE tt_value AS TABLE(val nvarchar(30)); 6 | 7 | --Create the function 8 | CREATE FUNCTION udf_sort(in it_table tt_value) 9 | RETURNS tt_value 10 | AS BEGIN 11 | DECLARE la_value NVARCHAR(30) ARRAY; 12 | DECLARE lv_linecount INT; --Number of lines 13 | DECLARE lv_round INT; --Current round 14 | DECLARE lv_line INT; --Current line 15 | DECLARE lv_tmp NVARCHAR(30); --For the exchange 16 | 17 | --Conversion of the table in an array: 18 | la_value = ARRAY_AGG(:it_table.val); 19 | 20 | --Determine the number of rows: 21 | SELECT COUNT(*) INTO lv_linecount FROM :it_table; 22 | 23 | FOR lv_round IN 1..:lv_linecount DO 24 | FOR lv_line IN 2..:lv_linecount DO 25 | IF :la_value[:lv_line-1] > :la_value[:lv_line] 26 | THEN --Exchange: 27 | lv_tmp = :la_value[:lv_line-1]; 28 | la_value[:lv_line-1] = :la_value[:lv_line]; 29 | la_value[:lv_line] = :lv_tmp; 30 | END IF; 31 | END FOR; --Line 32 | END FOR; --Round 33 | 34 | --Conversion of the sorted array in a table: 35 | rt_result = UNNEST(:la_value) AS (val); 36 | RETURN :rt_result; 37 | END; -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.35.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.35.sql 2 | -- Test of the sorting algorithm with data 3 | 4 | DO BEGIN 5 | DECLARE lt_testdata tt_value; 6 | DECLARE la_testdata NVARCHAR(30) ARRAY ; 7 | 8 | la_testdata = ARRAY('Z', 'Y', 'B', 'A'); 9 | 10 | lt_testdata = UNNEST(:la_testdata) AS ( val ); 11 | 12 | SELECT * FROM udf_sort(:lt_testdata); 13 | END; 14 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.37.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.37.sql 2 | -- Example of a log procedure with an autonomous transaction. 3 | 4 | CREATE PROCEDURE write_error_log ( 5 | IN iv_error_code INT, 6 | IN iv_error_message NVARCHAR(500) ) 7 | AS BEGIN 8 | BEGIN AUTONOMOUS TRANSACTION 9 | 10 | INSERT INTO error_log ( timestamp, 11 | errorcode, 12 | message ) 13 | VALUES ( current_timestamp, 14 | :iv_error_code, 15 | :iv_error_message ); 16 | END; 17 | END; 18 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.38.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.38.sql 2 | -- Example of dynamic SQL with a local temporary table 3 | 4 | DO BEGIN 5 | DECLARE lv_statement VARCHAR(1000); 6 | DECLARE CURSOR lr_tables 7 | FOR SELECT table_columns.table_name 8 | FROM table_columns 9 | INNER JOIN tables 10 | ON table_columns.table_Name = tables.table_name 11 | AND table_columns.schema_name = tables.schema_name 12 | AND tables.is_user_defined_type = 'FALSE' 13 | WHERE table_columns.schema_name = current_schema 14 | AND column_name = 'ID'; 15 | --Create the LTT 16 | CREATE LOCAL TEMPORARY TABLE #max_id(table_name NVARCHAR(256) 17 | , max_id INT ); 18 | 19 | FOR ls_tables AS lr_tables DO 20 | --Building the INSERT-Statement 21 | lv_statement = 'INSERT INTO #max_id SELECT ''' 22 | || ls_tables.table_name 23 | || ''' AS table_name, max(ID) AS max_id FROM ' 24 | || ls_tables.table_name || ';'; 25 | --Execution of the dynamic SQL 26 | EXEC :lv_statement ; 27 | END FOR; 28 | 29 | --Fetch the result from the LTT 30 | SELECT * FROM #max_id ORDER BY MAX_ID DESC; 31 | END; -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.39.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.39.sql 2 | -- Take over resultable of a dynamic SQL query in SQLScript 3 | 4 | CREATE PROCEDURE get_column_values 5 | (IN iv_column NVARCHAR(30), 6 | IN iv_table NVARCHAR(30), 7 | OUT ot_result TABLE(value NVARCHAR(100))) 8 | AS BEGIN 9 | DECLARE lv_sql NVARCHAR(1000) DEFAULT ''; 10 | lv_sql = 'SELECT DISTINCT ' 11 | || :iv_column 12 | || ' AS value FROM ' 13 | || :iv_table; 14 | EXEC lv_sql INTO ot_result; 15 | 16 | END; 17 | 18 | CALL get_column_values( 'TITLE', 'TASKS', ?); 19 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.4.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.4.sql 2 | -- Example for SELECT INTO in several scalar variables 3 | 4 | DO BEGIN 5 | DECLARE lv_assignee INT; 6 | DECLARE lv_status INT; 7 | 8 | SELECT assignee, 9 | status 10 | INTO lv_assignee , 11 | lv_status 12 | FROM tasks 13 | WHERE id = 1; 14 | 15 | SELECT lv_assignee, 16 | lv_status FROM DUMMY; 17 | END; -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.40.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.40.sql 2 | -- Transfer several scalar variables from a dynamic SQL query 3 | 4 | CREATE PROCEDURE get_min_max 5 | (IN iv_column NVARCHAR(30), 6 | IN iv_table NVARCHAR(30), 7 | OUT ev_min NVARCHAR(100), 8 | OUT ev_max NVARCHAR(100) ) 9 | AS BEGIN 10 | DECLARE lv_sql NVARCHAR(1000) DEFAULT ''; 11 | lv_sql = 'SELECT MIN(' || :iv_column 12 | ||'),MAX(' || :iv_column 13 | ||') FROM '|| :iv_table; 14 | EXEC lv_sql INTO ev_min, ev_max; 15 | END; 16 | 17 | CALL get_min_max( 'TITLE', 'TASKS', ?, ?); 18 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.41.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.41.sql 2 | -- Example for input parameters in dynamic SQL 3 | 4 | CREATE PROCEDURE count_id( IN iv_maxid INT, 5 | OUT ov_count1 INT, 6 | OUT ov_count2 INT, 7 | OUT ov_count3 INT ) 8 | AS BEGIN 9 | EXEC 'SELECT COUNT(*) FROM tasks WHERE id < ?' 10 | INTO ov_count1 11 | USING :iv_maxid; 12 | 13 | -- With named parameters 14 | EXEC 'SELECT COUNT(*) FROM tasks WHERE id < :iv_maxid' 15 | INTO ov_count2 16 | USING :iv_maxid; 17 | 18 | -- With dynamic generated SQL statement 19 | EXEC 'SELECT COUNT(*) FROM tasks WHERE id <' 20 | || :iv_maxid 21 | INTO ov_count3; 22 | END; 23 | 24 | CALL count_id( 10, ?, ?, ?); -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.42.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.42.sql 2 | -- Dynamic selection from a table variable 3 | 4 | CREATE PROCEDURE dynsel_from_local_table 5 | ( OUT ov_count INT ) 6 | AS BEGIN 7 | lt_tmp = SELECT id FROM tasks; 8 | EXECUTE IMMEDIATE 'SELECT COUNT(*) FROM :lt_tmp' 9 | INTO ov_count 10 | USING :lt_tmp; 11 | END; 12 | 13 | CALL dynsel_from_local_table(?); 14 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.43.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.43.sql 2 | -- Dynamic filtering with APPLY_FILTER 3 | 4 | CREATE PROCEDURE filtered_tasks ( 5 | IN iv_where VARCHAR(100), 6 | OUT rt_result TABLE ( id INT, 7 | status INT, 8 | title NVARCHAR(40) ) ) 9 | AS BEGIN 10 | lt_tmp = APPLY_FILTER(tasks, :iv_where); 11 | 12 | rt_result = SELECT id, 13 | status, 14 | title 15 | FROM :lt_tmp; 16 | END; 17 | 18 | CALL filtered_tasks('status in ( 1, 2)', ?); 19 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.44.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.44.sql 2 | -- Examples for raising user-defined exceptions 3 | 4 | --Only with error code and text: 5 | SIGNAL SQL_ERROR_CODE 10000 SET MESSAGE_TEXT = 'My error'; 6 | 7 | --or with a defined error name and text: 8 | DECLARE my_error CONDITION FOR SQL_ERROR_CODE 10000; 9 | ... 10 | SIGNAL my_error SET MESSAGE_TEXT = 'My error'; 11 | 12 | --or without error code and text: 13 | DECLARE my_error CONDITION; 14 | ... 15 | SIGNAL my_error; 16 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.45.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.45.sql 2 | -- Examples for error handling of SQL errors and user-defined errors 3 | 4 | CREATE PROCEDURE test_error_handling( 5 | IN iv_aktion VARCHAR(10)) 6 | AS BEGIN 7 | -- Declarations 8 | DECLARE lv_tmp INT; 9 | DECLARE error1 CONDITION ; 10 | DECLARE error2 CONDITION FOR SQL_ERROR_CODE 10001 ; 11 | DECLARE division_durch_0 CONDITION FOR SQL_ERROR_CODE 304; 12 | 13 | -- Error handler 14 | DECLARE EXIT HANDLER FOR error1 15 | write_error_log( ::sql_error_code, 16 | ::sql_error_message ); 17 | DECLARE EXIT HANDLER FOR error2 18 | write_error_log( ::sql_error_code, 'Error 2' ); 19 | DECLARE EXIT HANDLER FOR division_durch_0 20 | write_error_log( ::sql_error_code, 21 | 'SQL-Error: ' || ::sql_error_message ); 22 | 23 | -- Statements 24 | IF iv_aktion='F1' THEN 25 | SIGNAL error1 ; 26 | ELSEIF iv_aktion='F2' THEN 27 | SIGNAL error2; 28 | ELSEIF iv_aktion='D0' THEN 29 | SELECT 1/0 FROM dummy ; 30 | END IF; 31 | END; 32 | 33 | CALL test_error_handling('F1'); 34 | CALL test_error_handling('F2'); 35 | CALL test_error_handling('D0'); 36 | CALL show_error_log(); 37 | DROP PROCEDURE test_error_handling; 38 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.46.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.46.sql 2 | -- Example of error handling for procedure calls 3 | 4 | CREATE PROCEDURE raise_my_error 5 | AS 6 | BEGIN 7 | -- Declarations 8 | DECLARE my_error CONDITION FOR SQL_ERROR_CODE 10001; 9 | 10 | -- Statements 11 | SIGNAL my_error; 12 | END; 13 | 14 | CREATE PROCEDURE catch_my_error 15 | AS 16 | BEGIN 17 | -- Declarations 18 | DECLARE my_error CONDITION FOR SQL_ERROR_CODE 10001; 19 | 20 | -- Error handling 21 | DECLARE EXIT HANDLER FOR my_error 22 | CALL write_error_log(::SQL_ERROR_CODE, 'Cached!'); 23 | 24 | -- Statements 25 | CALL raise_my_error(); 26 | END; 27 | 28 | CALL catch_my_error; 29 | CALL show_error_log(); 30 | 31 | DROP PROCEDURE raise_my_error; 32 | DROP PROCEDURE catch_my_error; 33 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.47.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.47.sql 2 | -- Forwarding errors with RESIGNAL 3 | 4 | CREATE PROCEDURE demo_resignal 5 | AS BEGIN 6 | DECLARE EXIT HANDLER FOR SQLEXCEPTION 7 | BEGIN --Block for error handling 8 | IF ::sql_error_code > 219 --These could be interesting 9 | THEN 10 | CALL write_error_log(::sql_error_code, 11 | ::sql_error_message); 12 | ELSE 13 | RESIGNAL;--Better abort with these errors 14 | END IF; 15 | END;--End of the error handling 16 | 17 | ... 18 | END; 19 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.48.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.48.sql 2 | -- Error handler with enhancement of database schema and procedure in error text 3 | 4 | DECLARE EXIT HANDLER FOR SQLEXCEPTION 5 | RESIGNAL SET MESSAGE_TEXT = 'Procedure' 6 | || ::CURRENT_OBJECT_SCHEMA 7 | || '.' 8 | || ::CURRENT_OBJECT_NAME 9 | ||::SQL_ERROR_MESSAGE; 10 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.5.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.5.sql 2 | -- Example of error processing for SELECT INTO 3 | 4 | 5 | CREATE PROCEDURE get_assignee_status 6 | (IN iv_id INT, 7 | OUT ov_assignee INT, 8 | OUT ov_status INT ) 9 | AS BEGIN 10 | --Up to HANA 2.0 SPS03: 11 | DECLARE EXIT HANDLER FOR SQLEXCEPTION 12 | BEGIN 13 | ov_assignee = -1; 14 | ov_status = -1; 15 | END; 16 | 17 | SELECT assignee, 18 | status 19 | INTO ov_assignee , 20 | ov_status 21 | DEFAULT -1, --From HANA 2.0 SPS03: Defaultdvalues 22 | -1 --for variables at the assignment 23 | FROM tasks 24 | WHERE id = iv_id; 25 | 26 | END; 27 | 28 | CALL get_assignee_status(1, ?, ?); 29 | CALL get_assignee_status(-1, ?, ?); 30 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.6.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.6.sql 2 | -- Nested blocks and overlapping of variables 3 | 4 | DO 5 | BEGIN --Beginning of the outer block 6 | DECLARE var1 VARCHAR(10) default 'Outer'; 7 | DECLARE var2 VARCHAR(10) default 'Outer'; 8 | 9 | BEGIN --Beginning of the inner block 10 | DECLARE var1 VARCHAR(10);--Var1 declared again 11 | 12 | var1 = 'Inner'; 13 | var2 = 'Inner'; 14 | SELECT 'Inner block:' as comment, 15 | :var1, 16 | :var2 17 | FROM DUMMY; 18 | END;-- End of the inner block 19 | 20 | SELECT 'Outer block' as comment, 21 | :var1, 22 | :var2 23 | FROM DUMMY; 24 | END;--End of the outer block 25 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.7.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.7.sql 2 | -- Index-based access to table variables 3 | 4 | DO (OUT ot_result TABLE( id INT, 5 | title NVARCHAR(50))=>?) 6 | BEGIN 7 | ot_result = SELECT top 10 id, title FROM tasks; 8 | ot_result.title[1] = 'Title: ' || :ot_result.title[1]; 9 | END; 10 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.8.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.8.sql 2 | -- Index-based access with scalar expressions as an index 3 | 4 | DO (OUT ot_result TABLE(text NVARCHAR(100))=>?) 5 | BEGIN 6 | DECLARE indx integer; 7 | 8 | lt_tasks = SELECT TOP 10 * 9 | FROM tasks; 10 | lt_status = SELECT * 11 | FROM status_text 12 | WHERE langu = 'EN' 13 | ORDER BY id ASC; 14 | 15 | FOR indx IN 1..10 DO 16 | ot_result.text[:indx] = 17 | :lt_status.status_text[:lt_tasks.status[:indx]] 18 | || ' - ' 19 | || :lt_tasks.title[:indx]; 20 | END FOR; 21 | END; 22 | -------------------------------------------------------------------------------- /Listings/Chapter 6/EN_Listing 6.9.sql: -------------------------------------------------------------------------------- 1 | -- Listing 6.9.sql 2 | -- Access to non-existing rows 3 | 4 | DO (OUT ot_result TABLE( id INT, 5 | title NVARCHAR(50))=>?) 6 | BEGIN 7 | ot_result = SELECT TOP 10 id, title FROM tasks; 8 | 9 | ot_result.title[30] = :ot_result.title[1]; 10 | ot_result.title[1] = :ot_result.title[31]; 11 | END; 12 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.10.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.10.sql 2 | -- Definition of parameterized views 3 | 4 | CREATE VIEW invoices (IN iv_currency VARCHAR(5)) 5 | AS SELECT invoice_nr, 6 | SUM(amount*quantity) as amount, 7 | currency 8 | FROM invoice_position 9 | WHERE currency = :iv_currency 10 | GROUP BY invoice_nr, 11 | currency; 12 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.11.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.11.sql 2 | -- Example for the use of a sequence 3 | 4 | CREATE SEQUENCE countdown INCREMENT BY-1 5 | MAXVALUE 10 6 | MINVALUE 0 7 | CYCLE; 8 | DO BEGIN 9 | DECLARE lv_counter INT; 10 | DECLARE lv_tmp INT; 11 | DECLARE la_array INT ARRAY; 12 | 13 | FOR lv_counter IN 1..100 DO 14 | SELECT countdown.nextval 15 | INTO lv_tmp 16 | FROM DUMMY; 17 | la_array[:lv_counter] = lv_tmp; 18 | END FOR; 19 | lt_output = UNNEST(:la_array); 20 | SELECT * 21 | FROM :LT_OUTPUT; 22 | END; 23 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.12.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.12.sql 2 | -- Example of a trigger for an automatic change logging 3 | 4 | CREATE SEQUENCE lognr; --technical key of the log 5 | 6 | CREATE TABLE invoice_position( 7 | invoice_nr INT, 8 | position INT, 9 | product NVARCHAR(30), 10 | quantity INT, 11 | amount DEC(17,2), 12 | currency VARCHAR(5), 13 | primary key (invoice_nr, position) 14 | ); 15 | CREATE TABLE rp_log( 16 | log_nr INT, 17 | invoice_nr INT, 18 | position INT, 19 | users VARCHAR(80), 20 | datum DATE, 21 | zeit TIME, 22 | action VARCHAR(1) 23 | ); 24 | --Trigger for inserting 25 | CREATE TRIGGER rp_insert AFTER INSERT 26 | ON invoice_position 27 | REFERENCING NEW ROW ls_new 28 | FOR EACH ROW 29 | BEGIN 30 | INSERT INTO rp_log VALUES( lognr.nextval, 31 | :ls_new.invoice_nr, 32 | :ls_new.position, 33 | current_user, 34 | current_date, 35 | current_time, 36 | 'I'); 37 | END; 38 | 39 | --Trigger for updating 40 | CREATE TRIGGER rp_update AFTER UPDATE 41 | ON invoice_position 42 | REFERENCING NEW ROW ls_new 43 | FOR EACH ROW 44 | BEGIN 45 | INSERT INTO rp_log VALUES( lognr.nextval, 46 | :ls_new.invoice_nr, 47 | :ls_new.position, 48 | current_user, 49 | current_date, 50 | current_time, 51 | 'U'); 52 | END; 53 | 54 | INSERT INTO invoice_position 55 | VALUES (1, 10, 'Chocolate', 1, 1.99, 'EUR'); 56 | 57 | INSERT INTO invoice_position 58 | VALUES (1,20, 'Espresso coffee beans', 1, 13.99, 'EUR'); 59 | 60 | UPDATE invoice_position 61 | SET amount = '12.99' 62 | WHERE invoice_nr = 1 63 | AND position = 20; 64 | 65 | SELECT * FROM rp_log; 66 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.13.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.13.sql 2 | -- Assignment of OLD and NEW to local variables 3 | 4 | CREATE TRIGGER rp_update AFTER UPDATE 5 | ON invoice_position 6 | REFERENCING NEW ROW ls_new 7 | OLD ROW ls_old 8 | FOR EACH ROW 9 | ... 10 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.14.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.14.sql 2 | -- Parameterization for line-by-line processing 3 | 4 | CREATE TRIGGER rp_insert AFTER INSERT 5 | ON invoice_position 6 | REFERENCING NEW ROW ls_new 7 | FOR EACH ROW 8 | ... 9 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.15.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.15.sql 2 | -- Parameterization for processing per statement with table parameters 3 | 4 | CREATE TRIGGER rp_insert AFTER INSERT 5 | ON invoice_position 6 | REFERENCING NEW TABLE AS lt_new 7 | FOR EACH STATEMENT 8 | ... 9 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.2.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.2.sql 2 | -- Example of restrictions on individual columns 3 | 4 | CREATE TABLE status (id INT PRIMARY KEY, 5 | sort_nr INT NOT NULL UNIQUE, 6 | text NVARCHAR(30) ); 7 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.3.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.3.sql 2 | -- Example of multiple UNIQUE restrictions on multiple columns 3 | 4 | CREATE TABLE test_unique (a INT, 5 | b INT, 6 | c INT, 7 | UNIQUE(a, b), 8 | UNIQUE(b, c)); 9 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.4.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.4.sql 2 | -- Example of a composite primary key 3 | 4 | CREATE TABLE test_composite_key (a INT, 5 | b INT, 6 | c INT, 7 | PRIMARY KEY(a, b)); 8 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.5.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.5.sql 2 | -- Automatic number assignment 3 | 4 | CREATE COLUMN TABLE test_identity ( 5 | a INT GENERATED BY DEFAULT AS IDENTITY, 6 | b VARCHAR(10)); 7 | 8 | INSERT INTO test_identity (b) VALUES ('One'); 9 | INSERT INTO test_identity (b) VALUES ('Two'); 10 | INSERT INTO test_identity (a,b) VALUES (3, 'Three'); 11 | INSERT INTO test_identity (b) VALUES ('Four'); 12 | 13 | SELECT * FROM test_identity; 14 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.6.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.6.sql 2 | -- Creating a new table based on an SQL query 3 | 4 | CREATE TABLE tmp_tasks AS ( 5 | SELECT a.id, 6 | b.firstname, 7 | b.lastname, 8 | t.team_text 9 | FROM tasks AS a 10 | LEFT OUTER JOIN users AS b 11 | ON a.assignee = b.id 12 | LEFT OUTER JOIN team_text AS t 13 | ON b.team = t.id 14 | ) 15 | WITH DATA; 16 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.7.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.7.sql 2 | -- Example for changing table properties 3 | 4 | CREATE ROW TABLE demo_table( 5 | col1 INT, 6 | col2 INT 7 | ); 8 | 9 | --Adding a column 10 | ALTER TABLE demo_table ADD (col3 VARCHAR(20)); 11 | 12 | --Change column properties, e.g. set default value: 13 | ALTER TABLE demo_table ALTER (col1 INT DEFAULT 42); 14 | 15 | --Add the primary key definition: 16 | ALTER TABLE demo_table 17 | ADD CONSTRAINT pk PRIMARY KEY (col1, col2); 18 | 19 | --changing the type: 20 | ALTER TABLE demo_table COLUMN; 21 | 22 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.8.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.8.sql 2 | -- Example of the definition of a table type and use in a procedure definition 3 | 4 | CREATE TYPE my_type AS TABLE( 5 | col1 INT, 6 | col2 VARCHAR(10) ); 7 | 8 | CREATE PROCEDURE my_procedure( IN it_data my_type ) 9 | AS BEGIN 10 | ... 11 | -------------------------------------------------------------------------------- /Listings/Chapter 7/EN_Listing 7.9.sql: -------------------------------------------------------------------------------- 1 | -- Listing 7.9.sql 2 | -- Example of a view as a stored SELECT query 3 | 4 | CREATE TABLE invoice_position( 5 | invoice_nr INT, 6 | position INT, 7 | product NVARCHAR(30), 8 | quantity INT, 9 | amount DEC(17,2), 10 | currency VARCHAR(5), 11 | primary key (invoice_nr, position) 12 | ); 13 | CREATE VIEW invoices 14 | AS SELECT invoice_nr, 15 | SUM(amount*quantity) as amount, 16 | currency 17 | FROM invoice_position 18 | GROUP BY invoice_nr, 19 | currency; 20 | 21 | INSERT INTO invoice_position 22 | VALUES (1, 10, 'TVs', 1, 765.23, 'EUR'); 23 | INSERT INTO invoice_position 24 | VALUES (1, 20, 'Cable' , 1, 12.99 , 'EUR'); 25 | INSERT INTO invoice_position 26 | VALUES (1, 30, 'Batteries', 4, 1.99 , 'EUR'); 27 | INSERT INTO invoice_position 28 | VALUES (2, 10, 'Computer mouse', 1, 23.99 , 'EUR'); 29 | INSERT INTO invoice_position 30 | VALUES (3, 10, 'Cable' , 2, 12.99 , 'EUR'); 31 | INSERT INTO invoice_position 32 | VALUES (3, 20, 'Network swich' , 1, 27.99 , 'USD'); 33 | 34 | --SELECT query to the table 35 | SELECT invoice_nr, 36 | SUM(amount*quantity) as amount, 37 | currency 38 | FROM invoice_position 39 | GROUP BY invoice_nr, 40 | currency; 41 | 42 | --SELECT query on the VIEW 43 | SELECT * FROM invoices; 44 | -------------------------------------------------------------------------------- /Listings/Chapter 8/EN_Listing 8.1.abap: -------------------------------------------------------------------------------- 1 | -- Listing 8.1.abap 2 | -- Example of a simple AMDP method 3 | 4 | CLASS zcl_amdp_demo DEFINITION 5 | PUBLIC 6 | CREATE PUBLIC . 7 | 8 | PUBLIC SECTION. 9 | INTERFACES if_amdp_marker_hdb. 10 | TYPES gty_tt_countries TYPE TABLE OF t005t . 11 | METHODS get_countries 12 | IMPORTING 13 | VALUE(iv_langu) TYPE langu 14 | EXPORTING 15 | VALUE(et_country) TYPE gty_tt_countries 16 | CHANGING 17 | VALUE(cv_subrc) TYPE sy-subrc. 18 | ENDCLASS. 19 | 20 | CLASS zcl_amdp_demo IMPLEMENTATION. 21 | METHOD get_countries 22 | BY DATABASE PROCEDURE FOR HDB LANGUAGE SQLSCRIPT 23 | USING t005t. 24 | 25 | et_country = select * 26 | from t005t 27 | where spras = :iv_langu; 28 | 29 | SELECT CASE 30 | WHEN COUNT(*) > 0 31 | THEN 0 32 | ELSE 4 33 | END AS subrc 34 | INTO cv_subrc 35 | FROM :et_country; 36 | ENDMETHOD. 37 | ENDCLASS. 38 | -------------------------------------------------------------------------------- /Listings/Chapter 8/EN_Listing 8.10.abap: -------------------------------------------------------------------------------- 1 | -- Listing 8.10.abap 2 | -- Example for the implementation of a CDS table function 3 | 4 | CLASS zjb_cl_country DEFINITION PUBLIC. 5 | PUBLIC SECTION. 6 | INTERFACES if_amdp_marker_hdb. 7 | CLASS-METHODS get_country_text 8 | FOR TABLE FUNCTION z_country_text. 9 | ENDCLASS. 10 | 11 | CLASS zjb_cl_country IMPLEMENTATION. 12 | METHOD get_country_text BY DATABASE FUNCTION 13 | FOR HDB LANGUAGE SQLSCRIPT 14 | OPTIONS READ-ONLY 15 | USING t005t. 16 | RETURN SELECT mandt, 17 | land1 AS country, 18 | landx50 AS text 19 | FROM t005t 20 | WHERE spras = :sy_langu 21 | AND mandt = :mandt; 22 | ENDMETHOD. 23 | ENDCLASS. 24 | -------------------------------------------------------------------------------- /Listings/Chapter 8/EN_Listing 8.11.abap: -------------------------------------------------------------------------------- 1 | -- Listing 8.11.abap 2 | -- ABAP program for testing the CDS table function from the following example 3 | 4 | REPORT zjb_test . 5 | 6 | SELECT * 7 | FROM z_country_text 8 | INTO TABLE @DATA(lt_country) 9 | ##db_feature_mode[amdp_table_function]. 10 | 11 | cl_demo_output=>display( lt_country ). 12 | -------------------------------------------------------------------------------- /Listings/Chapter 8/EN_Listing 8.13.abap: -------------------------------------------------------------------------------- 1 | -- Listing 8.13.abap 2 | -- Generated UDF function for the AMDP function 3 | 4 | create function 5 | "ZJB_CL_COUNTRY=>GET_COUNTRY_TEXT" 6 | ( 7 | "MANDT" NVARCHAR (000003), 8 | "SY_LANGU" NVARCHAR (000001) 9 | ) 10 | returns table 11 | ( 12 | "MANDT" NVARCHAR (000003) , 13 | "COUNTRY" NVARCHAR (000003) , 14 | "TEXT" NVARCHAR (000050) 15 | ) 16 | language sqlscript sql security invoker as begin 17 | 18 | RETURN SELECT mandt, 19 | land1 AS country, 20 | landx50 AS text 21 | FROM "ZJB_CL_COUNTRY=>T005T#covw" 22 | WHERE spras = :SY_LANGU 23 | AND mandt = :MANDT; 24 | 25 | end; 26 | -------------------------------------------------------------------------------- /Listings/Chapter 8/EN_Listing 8.14.abap: -------------------------------------------------------------------------------- 1 | -- Listing 8.14.abap 2 | -- Example for the use of an AMDP function in another AMDP method 3 | 4 | CLASS zcl_amdp_func DEFINITION PUBLIC. 5 | 6 | PUBLIC SECTION. 7 | TYPES: BEGIN OF ty_s_country, 8 | mandt TYPE mandt, 9 | country TYPE land1, 10 | text TYPE landx50, 11 | END OF ty_s_country. 12 | TYPES ty_t_country TYPE STANDARD TABLE OF ty_s_country 13 | WITH DEFAULT KEY. 14 | 15 | INTERFACES if_amdp_marker_hdb. 16 | METHODS test_amdp_table_function 17 | IMPORTING VALUE(iv_langu) TYPE langu 18 | VALUE(iv_mandt) TYPE mandt 19 | EXPORTING VALUE(et_country) TYPE ty_t_country. 20 | 21 | PRIVATE SECTION. 22 | METHODS get_country_text 23 | IMPORTING VALUE(iv_langu) TYPE langu 24 | VALUE(iv_mandt) TYPE mandt 25 | RETURNING VALUE(rt_country) TYPE ty_t_country. 26 | ENDCLASS. 27 | 28 | CLASS zcl_amdp_func IMPLEMENTATION. 29 | 30 | METHOD test_amdp_table_function BY DATABASE PROCEDURE 31 | FOR HDB LANGUAGE SQLSCRIPT 32 | OPTIONS READ-ONLY 33 | USING zcl_amdp_func=>get_country_text. 34 | et_country = select * 35 | from "ZCL_AMDP_FUNC=>GET_COUNTRY_TEXT" 36 | ( iv_langu => :iv_langu, 37 | iv_mandt => :iv_mandt); 38 | ENDMETHOD. 39 | 40 | METHOD get_country_text BY DATABASE FUNCTION 41 | FOR HDB LANGUAGE SQLSCRIPT 42 | OPTIONS READ-ONLY 43 | USING t005t. 44 | RETURN SELECT mandt, 45 | land1 AS country, 46 | landx50 AS text 47 | FROM t005t 48 | WHERE spras = :iv_langu 49 | AND mandt = :iv_mandt; 50 | ENDMETHOD. 51 | 52 | ENDCLASS. 53 | -------------------------------------------------------------------------------- /Listings/Chapter 8/EN_Listing 8.5.abap: -------------------------------------------------------------------------------- 1 | -- Listing 8.5.abap 2 | -- Static Factory Method GET_INSTANCE in ABAP 3 | 4 | METHOD get_instance. 5 | DATA lv_classname TYPE classname. 6 | CASE sy-dbsys. 7 | WHEN 'HDB'. 8 | lv_classname = 'ZCL_READ_XYZ_AMDP'. 9 | WHEN OTHERS. 10 | lv_classname = 'ZCL_READ_XYZ_OSQL'. 11 | ENDCASE. 12 | 13 | CREATE OBJECT ro_instance TYPE (lv_classname). 14 | ENDMETHOD. 15 | -------------------------------------------------------------------------------- /Listings/Chapter 8/EN_Listing 8.6.abap: -------------------------------------------------------------------------------- 1 | CLASS zcl_amdp_call DEFINITION PUBLIC. 2 | 3 | PUBLIC SECTION. 4 | TYPES: BEGIN OF ty_s_price, 5 | item TYPE numc4, 6 | net_price TYPE wertv9, 7 | gross_price TYPE wertv9, 8 | vat TYPE wertv9, 9 | waehrs TYPE waers, 10 | END OF ty_s_price. 11 | 12 | TYPES ty_t_price TYPE STANDARD TABLE OF ty_s_price. 13 | 14 | INTERFACES if_amdp_marker_hdb. 15 | 16 | METHODS calculate_vat 17 | IMPORTING 18 | VALUE(iv_vat) TYPE int1 19 | CHANGING 20 | VALUE(ct_price) TYPE ty_t_price. 21 | 22 | METHODS calculate_gross_price 23 | IMPORTING 24 | VALUE(iv_vat) TYPE int1 25 | CHANGING 26 | VALUE(ct_price) TYPE ty_t_price. 27 | 28 | ENDCLASS. 29 | 30 | CLASS zcl_amdp_call IMPLEMENTATION. 31 | METHOD calculate_gross_price BY DATABASE PROCEDURE 32 | FOR HDB LANGUAGE SQLSCRIPT 33 | USING zcl_amdp_call=>calculate_vat. 34 | CALL "ZCL_AMDP_CALL=>CALCULATE_VAT"( 35 | iv_vat => :iv_vat, 36 | ct_price => :ct_price, 37 | ct_price__in__ => :ct_price ); 38 | 39 | ct_price = SELECT item, 40 | net_price, 41 | net_price + vat as gross_price, 42 | vat, 43 | waehrs 44 | FROM :ct_price; 45 | ENDMETHOD. 46 | 47 | METHOD calculate_vat BY DATABASE PROCEDURE 48 | FOR HDB LANGUAGE SQLSCRIPT. 49 | ct_price = SELECT item, 50 | net_price, 51 | gross_price, 52 | net_price * :iv_vat / 100 as vat, 53 | waehrs 54 | FROM :ct_price; 55 | 56 | ENDMETHOD. 57 | 58 | ENDCLASS. 59 | -------------------------------------------------------------------------------- /Listings/Chapter 8/EN_Listing 8.7.cds: -------------------------------------------------------------------------------- 1 | -- Listing 8.7.cds 2 | -- Basic structure of the definition of a CDS table function 3 | 4 | @EndUserText.label: 'Example for a table function' 5 | define table function Z_CDS_TF 6 | with parameters parameter_name : parameter_type 7 | returns { 8 | client_element_name : abap.clnt; 9 | element_name : element_type; 10 | } 11 | implemented by method class_name=>method_name;; 12 | -------------------------------------------------------------------------------- /Listings/Chapter 8/EN_Listing 8.9.cds: -------------------------------------------------------------------------------- 1 | -- Listing 8.9.cds 2 | -- Example for the definition of a CDS table function 3 | 4 | @EndUserText.label: 'Country texts' 5 | define table function z_country_text 6 | with parameters 7 | @Environment.systemField: #CLIENT mandt:mandt, 8 | @Environment.systemField: #SYSTEM_LANGUAGE sy_langu:langu 9 | returns { 10 | mandt:mandt; 11 | country:land1; 12 | text:landx50; 13 | } 14 | implemented by method zjb_cl_country=>get_country_text; 15 | -------------------------------------------------------------------------------- /Listings/Chapter 9/EN_Listing 9.1.sql: -------------------------------------------------------------------------------- 1 | -- Listing 9.1.sql 2 | -- Assignment of a sequential number for the RECORD field for sorting 3 | 4 | outtab = SELECT ... 5 | LPAD( RANK() OVER (ORDER BY ), 56, '0') 6 | AS "RECORD", 7 | SQL__PROCEDURE__SOURCE__RECORD 8 | FROM :intab ; 9 | -------------------------------------------------------------------------------- /Listings/Chapter 9/EN_Listing 9.2.sql: -------------------------------------------------------------------------------- 1 | -- Listing 9.2.sql 2 | -- Minimal implementation of an end routine 3 | 4 | METHOD procedure BY DATABASE PROCEDURE 5 | FOR HDB 6 | LANGUAGE SQLSCRIPT 7 | OPTIONS READ-ONLY. 8 | 9 | OUTTAB = SELECT * FROM :INTAB; 10 | ERRORTAB = SELECT '' AS ERROR_TEXT, 11 | '' AS SQL__PROCEDURE__SOURCE__RECORD 12 | FROM DUMMY 13 | WHERE DUMMY <> 'X'; 14 | ENDMETHOD. 15 | -------------------------------------------------------------------------------- /Listings/Chapter 9/EN_Listing 9.3.sql: -------------------------------------------------------------------------------- 1 | -- Listing 9.3.sql 2 | -- USING-clause in AMDP-routines 3 | 4 | METHOD procedure BY DATABASE PROCEDURE 5 | FOR HDB 6 | LANGUAGE SQLSCRIPT 7 | OPTIONS READ-ONLY 8 | USING /bic/AZJB_TEST2. 9 | 10 | OUTTAB = SELECT 11 | ... 12 | FROM :INTAB AS T1 13 | LEFT OUTER JOIN "/BIC/AZJB_TEST2" AS T2 14 | ON 15 | ... ; 16 | ERRORTAB = SELECT * FROM :ERRORTAB; 17 | ENDMETHOD. 18 | -------------------------------------------------------------------------------- /Listings/Chapter 9/EN_Listing 9.4.sql: -------------------------------------------------------------------------------- 1 | -- Listing 9.4.sql 2 | -- Protection against NULL values with COALESCE 3 | 4 | outtab = SELECT ... 5 | COALESCE( pplant.plantcat, ' ' ) AS plantcat, 6 | it.record , 7 | it.sql__procedure__source__record 8 | FROM :intab as it 9 | LEFT OUTER JOIN "/BI0/PPLANT" AS pplant 10 | ON it.plant = pplant.plant 11 | -------------------------------------------------------------------------------- /Listings/Chapter 9/EN_Listing 9.6.sql: -------------------------------------------------------------------------------- 1 | -- Listing 9.6.sql 2 | -- Simple expert routine 3 | 4 | METHOD procedure BY DATABASE PROCEDURE 5 | FOR HDB LANGUAGE SQLSCRIPT 6 | OPTIONS READ-ONLY 7 | USING /bi0/pmat_plant. 8 | 9 | outtab = select it.soursystem , 10 | it.plant , 11 | mat_plant.mat_plant , 12 | mat_plant.recordmode , 13 | mat_plant.abckey , 14 | 15 | ... 16 | 17 | mat_plant.price_unit , 18 | mat_plant.proctime , 19 | mat_plant.prodsched , 20 | mat_plant.profit_ctr , 21 | mat_plant.stge_pd_un , 22 | it.record , 23 | it.sql__procedure__source__record 24 | FROM :intab AS it 25 | INNER JOIN "/BI0/PMAT_PLANT" AS mat_plant 26 | ON it.soursystem = mat_plant.soursystem 27 | AND it.plant = mat_plant.plant; 28 | 29 | errortab = SELECT * FROM :errortab; 30 | ENDMETHOD. 31 | -------------------------------------------------------------------------------- /Listings/Chapter 9/EN_Listing 9.7.sql: -------------------------------------------------------------------------------- 1 | -- Listing 9.7.sql 2 | -- Simple error determination from the INTAB input data 3 | 4 | errortab = SELECT 'Currency is empty!' AS ERROR_TEXT, 5 | SQL__PROCEDURE__SOURCE__RECORD 6 | FROM :intab 7 | WHERE currency = ' ' 8 | AND amount <> 0; 9 | -------------------------------------------------------------------------------- /Listings/Chapter 9/EN_Listing 9.8.sql: -------------------------------------------------------------------------------- 1 | -- Listing 9.8.sql 2 | -- Error determination from OUTTAB 3 | 4 | outtab = SELECT it.plant, 5 | pplant.plantcat 6 | FROM :intab AS it 7 | LEFT OUTER JOIN "/BI0/PPLANT" AS pplant 8 | ON it.plant = pplant.plant; 9 | 10 | ERRORTAB = SELECT 'Error!' AS error_text, 11 | SQL__PROCEDURE__SOURCE__RECORD 12 | FROM :outtab 13 | WHERE plant = ' ' --Errors from INTAB 14 | OR plantcat IS NULL --Join unsuccessful 15 | -------------------------------------------------------------------------------- /Listings/Chapter 9/EN_Listing 9.9.sql: -------------------------------------------------------------------------------- 1 | -- Listing 9.9.sql 2 | -- Check for control characters 3 | outtab = SELECT * FROM :intab; 4 | errortab = SELECT 'Check field content!' AS ERROR_TEXT, 5 | SQL__PROCEDURE__SOURCE__RECORD 6 | FROM :intab 7 | WHERE text LIKE_REGEXPR '.*[[cntrl]].*' 8 | OR text LIKE '!%' 9 | OR text = '#'; 10 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQLScript_for_SAP_HANA 2 | Additional scripts and information about the **english** edition of the book [SQLScript](https://www.brandeis.de/en/category/sqlscript) for SAP HANA. Please note that the German edition of the book has a slightly different demo data model. The scripts are not compatible, because the names of the tables, functions and procedures are different. 3 | 4 | ## Installation of the Demo Data Model 5 | Behind the following links are the SQL scripts that create the data model and fill it with data. Please copy the contents of the individual scripts to the clipboard and then open an SQL console for the database schema of your choice, for example the personal schema of your database user. There you insert the script and execute it. 6 | 7 | #### For SQLScript Trainings 8 | * [Creating Database Tables](https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/master/demo_data_model/01_Create_Tables_EN.sql) 9 | * [Filling Database Tables - Part 1](https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/master/demo_data_model/03_Fill_Tables_EN.sql) 10 | * [Filling Database Tables - Part 2](https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/master/demo_data_model/03_Fill_Tables_EN_2.sql) 11 | 12 | #### Additionally for Book reference 13 | * [Creating Procedures and Functions](https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/master/demo_data_model/02_Create_Procedures_and_Functions_EN.sql) 14 | * [Check installation](https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/master/demo_data_model/04_Check_Installation_EN.sql) 15 | 16 | After each script, please check in the console output whether everything ran without errors. The last script queries the number of lines in the respective tables. This allows you to check whether the data was loaded correctly. 17 | 18 | You can also save the script files locally and customize them as you like. If, for example, the test data is too much for you, you can simply adapt the corresponding script. To delete the created database objects, there is also a suitable script: 19 | 20 | [Deleting Database Tables, Procedures, and Functions](https://raw.githubusercontent.com/captainabap/SQLScript_for_SAP_HANA/master/demo_data_model/05_Delete_Data_Model_EN.sql) 21 | 22 | 23 | ## Overview of the Demo Data Model 24 | 25 | ![Übersicht](https://github.com/captainabap/SQLScript_for_SAP_HANA/blob/master/A02_Demo_Datenmodell.png) 26 | -------------------------------------------------------------------------------- /demo_data_model/01_Create_Tables_EN.sql: -------------------------------------------------------------------------------- 1 | --Definition of data types and database tables 2 | create type id_text as table( 3 | id int, 4 | text nvarchar(20) 5 | ); 6 | 7 | create column table colors( 8 | color NVARCHAR(20) 9 | ); 10 | create column table sizes( 11 | size VARCHAR(5) 12 | ); 13 | CREATE COLUMN TABLE users( 14 | id INT PRIMARY KEY, 15 | firstname NVARCHAR(20), 16 | lastname NVARCHAR(20), 17 | email NVARCHAR(50), 18 | sex VARCHAR(1), 19 | team int 20 | ); 21 | create column table team_text( 22 | id int , 23 | langu varchar(2), 24 | team_text nvarchar(20), 25 | primary key (id, langu) 26 | ); 27 | create column table projects( 28 | id INT PRIMARY KEY, 29 | title NVARCHAR(40), 30 | project_manager INT, 31 | estimated_effort INT, 32 | start_date DATE, 33 | status int 34 | ); 35 | create column table tasks( 36 | id INT PRIMARY KEY, 37 | project INT, 38 | title NVARCHAR(40), 39 | description CLOB, 40 | status INT, 41 | assignee INT, 42 | planned_effort INT, 43 | effort INT, 44 | create_date DATE, 45 | due_date DATE, 46 | completed INT 47 | ); 48 | 49 | create table status(id int primary key , is_final boolean, is_open boolean); 50 | 51 | create column table status_Text( 52 | id INT, 53 | langu VARCHAR(2), 54 | status_text NVARCHAR(20), 55 | PRIMARY KEY ( 56 | id, 57 | langu 58 | ) 59 | ); 60 | create column table tasks_log( 61 | task INT, 62 | timestamp TIMESTAMP, 63 | status INT, 64 | users INT, 65 | PRIMARY KEY ( 66 | task, 67 | timestamp 68 | ) 69 | ); 70 | create column table dats_date( 71 | id INT PRIMARY KEY, 72 | calday VARCHAR(8) 73 | ); 74 | 75 | create column table error_log( 76 | id int primary key GENERATED BY DEFAULT AS IDENTITY, 77 | timestamp timestamp, 78 | errorcode int, 79 | message Nvarchar(500) 80 | ); 81 | -------------------------------------------------------------------------------- /demo_data_model/02_Create_Procedures_and_Functions_EN.sql: -------------------------------------------------------------------------------- 1 | 2 | --Create procedures and functions 3 | CREATE PROCEDURE statustexts( 4 | IN iv_langu VARCHAR(2), 5 | OUT et_result TABLE ( 6 | id INT, 7 | status_text NVARCHAR(100) 8 | ) 9 | ) 10 | AS 11 | BEGIN 12 | et_result = SELECT id, 13 | status_text 14 | FROM status_text 15 | WHERE langu = iv_langu; 16 | END; 17 | 18 | CREATE FUNCTION udf_statustexts (iv_langu VARCHAR(2)) 19 | RETURNS TABLE ( id INT, 20 | status_text VARCHAR(20) ) 21 | AS BEGIN 22 | RETURN SELECT id, 23 | status_text 24 | FROM status_text 25 | WHERE langu = :iv_langu; 26 | END; 27 | 28 | 29 | create function udf_username(iv_id int) 30 | returns rv_name nvarchar(42) 31 | as begin 32 | select lastname || ', ' || firstname into rv_name from users where id = :iv_id; 33 | end; 34 | 35 | create function udf_tasks_in_status(iv_status int) 36 | returns table(id int, assignee int, status int, title varchar(20)) 37 | as begin 38 | return select id, assignee, status, title from tasks where status = :iv_status; 39 | end; 40 | 41 | CREATE FUNCTION udf_name ( iv_firstname NVARCHAR(20), 42 | iv_lastname NVARCHAR(20) ) 43 | RETURNS rv_name NVARCHAR(42) 44 | AS 45 | BEGIN 46 | rv_name = :iv_lastname || ', ' || :iv_firstname; 47 | END; 48 | 49 | 50 | create function udf_int_min(iv_wert1 int, iv_wert2 int) 51 | returns rv_result int 52 | as begin 53 | select case when :iv_wert1 < :iv_wert2 54 | then :iv_wert1 55 | else :iv_wert2 end into rv_result from dummy; 56 | end; 57 | 58 | create function udf_int_max(iv_wert1 int, iv_wert2 int) 59 | returns rv_result int 60 | as begin 61 | select case when :iv_wert1 > :iv_wert2 62 | then :iv_wert1 63 | else :iv_wert2 end into rv_result from dummy; 64 | end; 65 | 66 | create function udf_tage(id int, iv_von date, iv_bis date) 67 | returns table (id int, datum date) 68 | as begin 69 | return SELECT :id as id, 70 | GENERATED_PERIOD_START as datum 71 | FROM SERIES_GENERATE_DATE( INCREMENT_BY => 'INTERVAL 1 DAY', 72 | MIN_VALUE => :iv_von, 73 | MAX_VALUE => :iv_bis ) 74 | UNION 75 | SELECT :ID as id, 76 | :iv_bis as datum 77 | from dummy; 78 | end; 79 | 80 | create procedure close_tasks(in iv_project int) 81 | as begin 82 | update tasks set status = 5 where project = :iv_project; 83 | end; 84 | 85 | CREATE PROCEDURE write_error_log ( 86 | IN iv_error_code INT, 87 | IN iv_error_message NVARCHAR(500) 88 | ) 89 | AS 90 | BEGIN 91 | BEGIN 92 | AUTONOMOUS TRANSACTION 93 | 94 | INSERT INTO error_log ( 95 | timestamp, 96 | errorcode, 97 | message 98 | ) 99 | VALUES ( 100 | current_timestamp, 101 | :iv_error_code, 102 | :iv_error_message 103 | ); 104 | END; 105 | END; 106 | 107 | create procedure show_error_log(in iv_seconds int default 10) 108 | as begin 109 | select * from error_log where timestamp > add_seconds( current_timestamp, -1 * iv_seconds ) order by id desc; 110 | end; 111 | -------------------------------------------------------------------------------- /demo_data_model/04_Check_Installation_EN.sql: -------------------------------------------------------------------------------- 1 | 2 | select count(*) as cnt, 'users' as tab from users --shoud be 30 3 | UNION 4 | select count(*) as cnt, 'projects' as tab from projects --shoud be 5 5 | UNION 6 | select count(*) as cnt, 'tasks' as tab from tasks --shoud be 1000 7 | UNION 8 | select count(*) as cnt, 'status' as tab from status --shoud be 6 9 | UNION 10 | select count(*) as cnt, 'status_text' as tab from status_text --should be 11 11 | UNION 12 | select count(*) as cnt, 'team_text' as tab from team_text --should be 14 13 | UNION 14 | select count(*) as cnt, 'tasks_log' as tab from tasks_log --should be empty 15 | UNION 16 | select count(*) as cnt, 'dats_date' as tab from dats_date --should be empty 17 | UNION 18 | select count(*) as cnt, 'colors' as tab from colors --should be empty 19 | UNION 20 | select count(*) as cnt, 'sizes' as tab from sizes; --should be empty 21 | -------------------------------------------------------------------------------- /demo_data_model/05_Delete_Data_Model_EN.sql: -------------------------------------------------------------------------------- 1 | --Delete the data model 2 | drop table users; 3 | drop table projects; 4 | drop table tasks; 5 | drop table status; 6 | drop table status_text; 7 | drop table tasks_log; 8 | drop table dats_date; 9 | drop table colors; 10 | drop table sizes; 11 | drop table team_text; 12 | drop table error_log; 13 | drop procedure statustexts; 14 | drop function udf_statustexts; 15 | drop function udf_tasks_in_status; 16 | drop function udf_username; 17 | drop function udf_int_min; 18 | drop function udf_int_max; 19 | drop function udf_name; 20 | drop function udf_tage; 21 | drop procedure write_error_log; 22 | drop procedure show_error_log; 23 | drop procedure close_tasks; 24 | drop type id_text; 25 | -------------------------------------------------------------------------------- /demo_data_model/generate_analytical_data.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE Countries ( 2 | COUNTRY VARCHAR(2) NOT NULL primary key, 3 | TEXT VARCHAR(255) NOT NULL 4 | ); 5 | 6 | 7 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('AF', 'Afghanistan'); 8 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('EG', 'Egypt'); 9 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('AL', 'Albania'); 10 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('DZ', 'Algeria'); 11 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('AD', 'Andorra'); 12 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('AO', 'Angola'); 13 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('AR', 'Argentina'); 14 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('AM', 'Armenia'); 15 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('AU', 'Australia'); 16 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('AT', 'Austria'); 17 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('AZ', 'Azerbaijan'); 18 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BH', 'Bahrain'); 19 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BD', 'Bangladesh'); 20 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BY', 'Belarus'); 21 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BE', 'Belgium'); 22 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BZ', 'Belize'); 23 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BJ', 'Benin'); 24 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BO', 'Bolivia'); 25 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BA', 'Bosnia and Herzegovina'); 26 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BW', 'Botswana'); 27 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BR', 'Brazil'); 28 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BN', 'Brunei'); 29 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BG', 'Bulgaria'); 30 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BF', 'Burkina Faso'); 31 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('BI', 'Burundi'); 32 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('KH', 'Cambodia'); 33 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CM', 'Cameroon'); 34 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CA', 'Canada'); 35 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CF', 'Central African Republic'); 36 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('TD', 'Chad'); 37 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CL', 'Chile'); 38 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CN', 'China'); 39 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CO', 'Colombia'); 40 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('KM', 'Comoros'); 41 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CD', 'Democratic Republic of the Congo'); 42 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CG', 'Republic of the Congo'); 43 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CR', 'Costa Rica'); 44 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('HR', 'Croatia'); 45 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CU', 'Cuba'); 46 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CY', 'Cyprus'); 47 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('CZ', 'Czech Republic'); 48 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('DK', 'Denmark'); 49 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('DJ', 'Djibouti'); 50 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('DO', 'Dominican Republic'); 51 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('EC', 'Ecuador'); 52 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('SV', 'El Salvador'); 53 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('GQ', 'Equatorial Guinea'); 54 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('ER', 'Eritrea'); 55 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('EE', 'Estonia'); 56 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('ET', 'Ethiopia'); 57 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('FI', 'Finland'); 58 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('FR', 'France'); 59 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('GA', 'Gabon'); 60 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('GM', 'Gambia'); 61 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('GE', 'Georgia'); 62 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('DE', 'Germany'); 63 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('GH', 'Ghana'); 64 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('GR', 'Greece'); 65 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('GT', 'Guatemala'); 66 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('GN', 'Guinea'); 67 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('GW', 'Guinea-Bissau'); 68 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('GY', 'Guyana'); 69 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('HT', 'Haiti'); 70 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('HN', 'Honduras'); 71 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('HU', 'Hungary'); 72 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('IS', 'Iceland'); 73 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('IN', 'India'); 74 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('ID', 'Indonesia'); 75 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('IR', 'Iran'); 76 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('IQ', 'Iraq'); 77 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('IE', 'Ireland'); 78 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('IL', 'Israel'); 79 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('IT', 'Italy'); 80 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('JM', 'Jamaica'); 81 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('JP', 'Japan'); 82 | INSERT INTO Countries (COUNTRY, TEXT) VALUES ('JO', 'Jordan'); 83 | 84 | -------------------------------------------------------------------- 85 | CREATE COLUMN TABLE "PCA_PLAN"( 86 | "COMPCODE" NVARCHAR(8) DEFAULT '' NOT NULL, 87 | "ACCOUNT" NVARCHAR(6) DEFAULT '' NOT NULL, 88 | "CURR" NVARCHAR(5) DEFAULT '' NOT NULL, 89 | "FISCYEAR" NVARCHAR(4) DEFAULT '' NOT NULL, 90 | "AMOUNT_01" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 91 | "AMOUNT_02" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 92 | "AMOUNT_03" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 93 | "AMOUNT_04" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 94 | "AMOUNT_05" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 95 | "AMOUNT_06" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 96 | "AMOUNT_07" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 97 | "AMOUNT_08" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 98 | "AMOUNT_09" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 99 | "AMOUNT_10" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 100 | "AMOUNT_11" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 101 | "AMOUNT_12" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 102 | CONSTRAINT "ZPCA_PLAN~0" PRIMARY KEY INVERTED INDIVIDUAL( 103 | "COMPCODE", 104 | "ACCOUNT", 105 | "CURR", 106 | "FISCYEAR" 107 | ) 108 | ) COLUMN LOADABLE 109 | UNLOAD PRIORITY 5 AUTO MERGE; 110 | 111 | CREATE COLUMN TABLE "RECORDS"( 112 | "BUDAT" NVARCHAR(8) DEFAULT '00000000' NOT NULL, 113 | "VALTYPE" NVARCHAR(2) DEFAULT '' NOT NULL, 114 | "ACCOUNT" NVARCHAR(6) DEFAULT '' NOT NULL, 115 | "AMOUNT" DECIMAL(17, 2) DEFAULT 0 NOT NULL, 116 | "CURR" NVARCHAR(5) DEFAULT '' NOT NULL, 117 | CONSTRAINT "RECORDS~0" PRIMARY KEY INVERTED INDIVIDUAL( 118 | "BUDAT", 119 | "VALTYPE", 120 | "ACCOUNT" 121 | ) 122 | ) COLUMN LOADABLE 123 | UNLOAD PRIORITY 5 AUTO MERGE; 124 | 125 | do begin 126 | declare la_nr varchar(2) array = array( '01', '02', '03', '04', '05', '07', '08', '10', '20', '40', '50', '60', '70', '90'); 127 | 128 | lt_NR = unnest( :la_nr ) as ( nr ); 129 | accounts = select nr1.nr||nr2.nr||nr3.nr as account, 130 | lpad(ceil(rand()*5)*10, 4, '0') as acctyp 131 | from :lt_nr as nr1 132 | cross join :lt_nr as nr2 133 | cross join :lt_nr as nr3 ; 134 | 135 | compcodes = select country||'01'as compcode from countries union all 136 | select country||'02'as compcode from countries union all 137 | select country||'03'as compcode from countries ; 138 | 139 | plan = ( select *, 140 | (1 + rand( ) * 0.4) * amount_01 as amount_02, 141 | (1 + rand( ) * 0.4) * amount_01 as amount_03, 142 | (1 + rand( ) * 0.4) * amount_01 as amount_04, 143 | (1 + rand( ) * 0.4) * amount_01 as amount_05, 144 | (1 + rand( ) * 0.4) * amount_01 as amount_06, 145 | (1 + rand( ) * 0.4) * amount_01 as amount_07, 146 | (1 + rand( ) * 0.4) * amount_01 as amount_08, 147 | (1 + rand( ) * 0.4) * amount_01 as amount_09, 148 | (1 + rand( ) * 0.4) * amount_01 as amount_10, 149 | (1 + rand( ) * 0.4) * amount_01 as amount_11, 150 | (1 + rand( ) * 0.4) * amount_01 as amount_12 151 | from ( 152 | 153 | 154 | select o.compcode, 155 | a.account, 156 | 'EUR' as curr, 157 | y.fiscyear, 158 | y.factor * (1+ rand( )*0.4) * a.factor * o.factor * 1000000 as amount_01 159 | from (select compcode, rand( ) as factor from :compcodes) as o 160 | cross join (select account, rand() as factor from :accounts ) as a 161 | cross join ( select year(add_years(current_date, 0)) as fiscyear, 1.1 as factor from dummy union 162 | select year(add_years(current_date, -1)) as fiscyear, 1.2 as factor from dummy union 163 | select year(add_years(current_date, -2)) as fiscyear, 1.2 as factor from dummy union 164 | select year(add_years(current_date, -3)) as fiscyear, 1.2 as factor from dummy ) as y 165 | 166 | ) ); 167 | 168 | lt_valtype = select '10' as valtype from dummy union 169 | select '20' as valtype from dummy union 170 | select '30' as valtype from dummy; 171 | 172 | tr_data = select to_dats(d.generated_period_start) as budat, 173 | v.valtype , 174 | a.account, 175 | rand( ) * 100000 as amount , 176 | 'EUR' as currency 177 | from :accounts as a 178 | cross join :lt_valtype as v 179 | cross join 180 | public.SERIES_GENERATE_DATE( INCREMENT_BY => 'INTERVAL 1 DAY', 181 | MIN_VALUE =>add_days(current_date, -365) , 182 | MAX_VALUE =>current_date ) as d 183 | 184 | ; 185 | select * from :compcodes; 186 | select * from :accounts; 187 | select * from :tr_data; 188 | insert into records (select * from :tr_data); 189 | insert into pca_plan (select * from :plan); 190 | end; 191 | 192 | --------------------------------------------------------------------------------