From 7e34069dd9f3ff93afef94377ee7fab69e5ec08a Mon Sep 17 00:00:00 2001 From: Ravisankar Pandian Date: Tue, 20 Aug 2024 19:33:01 +0530 Subject: [PATCH 1/2] Added two procedures to populate the tabels employee and department Signed-off-by: Ravisankar Pandian --- qddssrc/popdept.sql | 36 ++++++++++++++++++++++++++ qddssrc/popemp.sql | 63 +++++++++++++++++++++++++++++++++++++++++++++ 2 files changed, 99 insertions(+) create mode 100644 qddssrc/popdept.sql create mode 100644 qddssrc/popemp.sql diff --git a/qddssrc/popdept.sql b/qddssrc/popdept.sql new file mode 100644 index 0000000..82e13e1 --- /dev/null +++ b/qddssrc/popdept.sql @@ -0,0 +1,36 @@ +create or replace procedure popdept() +language sql +Result Sets 0 +Modifies SQL Data +Specific popdept +begin + declare i int default 1; + declare deptno char(3); + declare deptname varchar(36); + declare mgrno char(6); + declare admrdept char(3); + declare loc char(16); + + while i <= 5 do + -- Generate random data (you can adjust this as needed) + set deptno = right('000' || cast(rand()*1000 as int), 3); + set mgrno = right('00000' || cast(rand()*1000000 as int), 6); + set admrdept = right('000' || cast(rand()*1000 as int), 3); + set loc = 'Location ' || deptno; + + -- Assign department names based on specified categories + case + when i = 1 then set deptname = 'Admin'; + when i = 2 then set deptname = 'IT'; + when i = 3 then set deptname = 'Finance'; + when i = 4 then set deptname = 'Management'; + when i = 5 then set deptname = 'HR'; + end case; + + -- Insert into department table + insert into department (deptno, deptname, mgrno, admrdept, location) + values (deptno, deptname, mgrno, admrdept, loc); + + set i = i + 1; + end while; +end; \ No newline at end of file diff --git a/qddssrc/popemp.sql b/qddssrc/popemp.sql new file mode 100644 index 0000000..f0d86ed --- /dev/null +++ b/qddssrc/popemp.sql @@ -0,0 +1,63 @@ +create or replace procedure popemp() +P1: BEGIN + declare v_url CLOB(10M); + declare v_response CLOB(10M); + declare v_dept_name varchar(36); + declare v_mgr_no char(6); + declare v_admr_dept char(3); + declare v_location char(16); + declare v_emp_no char(6); + declare v_first_name varchar(12); + declare v_mid_init char(1); + declare v_last_name varchar(15); + declare v_work_dept char(3); + declare v_phone_no char(4); + declare v_hire_date date; + declare v_job char(8); + declare v_ed_level SMALLint; + declare v_sex char(1); + declare v_birth_date date; + declare v_salary decimal(9,2); + declare v_bonus decimal(9,2); + declare v_comm decimal(9,2); + declare i int default 1; + + + + + -- Populate EMPLOYEE table + while i <= 200 DO + set v_url = 'https://randomuser.me/api/?nat=in'; + set v_response = SYSTOOLS.HTTPGETCLOB(v_url, NULL); + set v_emp_no = i; + set v_first_name = json_value(v_response, '$.results[0].name.first'); + set v_mid_init = substr(json_value(v_response, '$.results[0].name.first'), 1, 1); + set v_last_name = json_value(v_response, '$.results[0].name.last'); + + -- Assign a random department from DEPARTMENT table + select deptno + into v_work_dept + from department + order by rand() + fetch first row only; + + set v_phone_no = substr(HEX(rand()), 1, 4); + set v_hire_date = date('2023-01-01') + int(rand() * 365 * 10) DAYS; + set v_job = 'JOB' || substr(HEX(rand()), 1, 4); + set v_ed_level = 12 + int(rand() * 8); + set v_sex = substr(json_value(v_response, '$.results[0].gender'),1,1); + set v_birth_date = date('1960-01-01') + int(rand() * 365 * 50) DAYS; + set v_salary = decimal(30000 + rand() * 70000, 9, 2); + set v_bonus = decimal(rand() * 10000, 9, 2); + set v_comm = decimal(rand() * 5000, 9, 2); + + + insert into EMPLOYEE + (EMPNO, FIRSTNME, MIDINIT, LASTNAME, WORKDEPT, PHONENO, HIREdate, JOB, EDLEVEL, SEX, BIRTHdate, SALARY, BONUS, COMM) + VALUES (v_emp_no, v_first_name, v_mid_init, v_last_name, v_work_dept, v_phone_no, v_hire_date, v_job, v_ed_level, + v_sex, v_birth_date, v_salary, v_bonus, v_comm); + + set i = i + 1; + + end while; +end P1; \ No newline at end of file From c55378a5b84067279bb3081a9758092b76d405df Mon Sep 17 00:00:00 2001 From: Ravisankar Pandian Date: Wed, 21 Aug 2024 03:50:47 +0530 Subject: [PATCH 2/2] Added Banner & replaced HTTPGETCLOB with HTTP_GET Signed-off-by: Ravisankar Pandian --- qddssrc/popdept.sql | 6 +- qddssrc/popemp.sql | 142 ++++++++++++++++++++++++++------------------ 2 files changed, 89 insertions(+), 59 deletions(-) diff --git a/qddssrc/popdept.sql b/qddssrc/popdept.sql index 82e13e1..8c7af15 100644 --- a/qddssrc/popdept.sql +++ b/qddssrc/popdept.sql @@ -1,3 +1,7 @@ +------------------------------------------------------------------------------- +-- This procedure will create 5 records into the department table +------------------------------------------------------------------------------- + create or replace procedure popdept() language sql Result Sets 0 @@ -29,7 +33,7 @@ begin -- Insert into department table insert into department (deptno, deptname, mgrno, admrdept, location) - values (deptno, deptname, mgrno, admrdept, loc); + values (deptno, deptname, mgrno, admrdept, loc) with nc; set i = i + 1; end while; diff --git a/qddssrc/popemp.sql b/qddssrc/popemp.sql index f0d86ed..1f94b99 100644 --- a/qddssrc/popemp.sql +++ b/qddssrc/popemp.sql @@ -1,63 +1,89 @@ -create or replace procedure popemp() +------------------------------------------------------------------------------- +-- This procedure will use HTTP_GET api to fetch data from randomuser.me/api +-- You may specify the Nationality to generate country specific data like ('fr') or ('in') +-- The default nationality is ('gb'). +-- For every run, this procedure will add 200 records to the employee table. +------------------------------------------------------------------------------- +create or replace procedure popemp( + in Nationality char(2) default 'gb' +) +language sql +Result Sets 0 +Modifies SQL Data +Specific popemp + P1: BEGIN - declare v_url CLOB(10M); - declare v_response CLOB(10M); - declare v_dept_name varchar(36); - declare v_mgr_no char(6); - declare v_admr_dept char(3); - declare v_location char(16); - declare v_emp_no char(6); - declare v_first_name varchar(12); - declare v_mid_init char(1); - declare v_last_name varchar(15); - declare v_work_dept char(3); - declare v_phone_no char(4); - declare v_hire_date date; - declare v_job char(8); - declare v_ed_level SMALLint; - declare v_sex char(1); - declare v_birth_date date; - declare v_salary decimal(9,2); - declare v_bonus decimal(9,2); - declare v_comm decimal(9,2); - declare i int default 1; + declare v_url CLOB(10M); + declare v_response CLOB(10M); + declare v_dept_name varchar(36); + declare v_mgr_no char(6); + declare v_admr_dept char(3); + declare v_location char(16); + declare v_emp_no char(6); + declare v_first_name varchar(12); + declare v_mid_init char(1); + declare v_last_name varchar(15); + declare v_work_dept char(3); + declare v_phone_no char(4); + declare v_hire_date date; + declare v_job char(8); + declare v_ed_level SMALLint; + declare v_sex char(1); + declare v_birth_date date; + declare v_salary decimal(9,2); + declare v_bonus decimal(9,2); + declare v_comm decimal(9,2); + declare i int; + declare j int; + + -- Get the latest Employee number available in the table + select count(empno)+1, count(1)+200 + into i, j + from employee; + -- Populate EMPLOYEE table + while i <= j do + set v_url = 'https://randomuser.me/api/?nat=' || Nationality ; + + --------------------------------------------------------------- + --Note: If you're getting a run time error as below: + -- HTTP_GET in SYSTOOLS type *N not found. + --then you're probably on IBMi version 7.4 or below, so use HTTPGETCLOB instead of HTTP_GET + --------------------------------------------------------------- + set v_response = SYSTOOLS.HTTP_GET(v_url, NULL); + -- set v_response = SYSTOOLS.HTTPGETCLOB(v_url, NULL); + + set v_emp_no = i; + set v_first_name = json_value(v_response, '$.results[0].name.first'); + set v_mid_init = substr(json_value(v_response, '$.results[0].name.first'), 1, 1); + set v_last_name = json_value(v_response, '$.results[0].name.last'); + + -- Assign a random department from DEPARTMENT table + select deptno + into v_work_dept + from department + order by rand() + fetch first row only; + + set v_phone_no = substr(HEX(rand()), 1, 4); + set v_hire_date = date('2023-01-01') + int(rand() * 365 * 10) DAYS; + set v_job = 'JOB' || substr(HEX(rand()), 1, 4); + set v_ed_level = 12 + int(rand() * 8); + set v_sex = substr(json_value(v_response, '$.results[0].gender'),1,1); + set v_birth_date = date('1960-01-01') + int(rand() * 365 * 50) DAYS; + set v_salary = decimal(30000 + rand() * 70000, 9, 2); + set v_bonus = decimal(rand() * 10000, 9, 2); + set v_comm = decimal(rand() * 5000, 9, 2); - - -- Populate EMPLOYEE table - while i <= 200 DO - set v_url = 'https://randomuser.me/api/?nat=in'; - set v_response = SYSTOOLS.HTTPGETCLOB(v_url, NULL); - set v_emp_no = i; - set v_first_name = json_value(v_response, '$.results[0].name.first'); - set v_mid_init = substr(json_value(v_response, '$.results[0].name.first'), 1, 1); - set v_last_name = json_value(v_response, '$.results[0].name.last'); - - -- Assign a random department from DEPARTMENT table - select deptno - into v_work_dept - from department - order by rand() - fetch first row only; - - set v_phone_no = substr(HEX(rand()), 1, 4); - set v_hire_date = date('2023-01-01') + int(rand() * 365 * 10) DAYS; - set v_job = 'JOB' || substr(HEX(rand()), 1, 4); - set v_ed_level = 12 + int(rand() * 8); - set v_sex = substr(json_value(v_response, '$.results[0].gender'),1,1); - set v_birth_date = date('1960-01-01') + int(rand() * 365 * 50) DAYS; - set v_salary = decimal(30000 + rand() * 70000, 9, 2); - set v_bonus = decimal(rand() * 10000, 9, 2); - set v_comm = decimal(rand() * 5000, 9, 2); + + insert into EMPLOYEE + (EMPNO, FIRSTNME, MIDINIT, LASTNAME, WORKDEPT, PHONENO, HIREdate, JOB, EDLEVEL, SEX, BIRTHdate, SALARY, BONUS, COMM) + VALUES (v_emp_no, v_first_name, v_mid_init, v_last_name, v_work_dept, v_phone_no, v_hire_date, v_job, v_ed_level, + v_sex, v_birth_date, v_salary, v_bonus, v_comm) with nc; + + set i = i + 1; + + end while; +end P1; - - insert into EMPLOYEE - (EMPNO, FIRSTNME, MIDINIT, LASTNAME, WORKDEPT, PHONENO, HIREdate, JOB, EDLEVEL, SEX, BIRTHdate, SALARY, BONUS, COMM) - VALUES (v_emp_no, v_first_name, v_mid_init, v_last_name, v_work_dept, v_phone_no, v_hire_date, v_job, v_ed_level, - v_sex, v_birth_date, v_salary, v_bonus, v_comm); - - set i = i + 1; - - end while; -end P1; \ No newline at end of file