├── MILES_FROM_KUBE-PAK ├── README.md ├── User_Statistics.sql └── fishes.txt /MILES_FROM_KUBE-PAK: -------------------------------------------------------------------------------- 1 | drop function MILESFKP; -- Miles from Kube-Pak 194 County Rd 526, Allentown, NJ 08501 2 | -- Create SQL Function 3 | CREATE OR REPLACE FUNCTION MILESFKP (inDest char(256)) 4 | 5 | RETURNS numeric(7, 2) 6 | LANGUAGE SQL 7 | 8 | BEGIN 9 | -- DECLARE outMeters int; -- Earth is 40.075 million m (40,075,000m) 10 | DECLARE outMiles numeric(7, 2); -- Earth is 24,901 mi 11 | 12 | DECLARE GOOGLE_URL varchar(600); 13 | 14 | Set outMiles = -1; 15 | Set GOOGLE_URL = 'https://maps.googleapis.com/maps/api/distancematrix/xml?' || 16 | 'units=imperial'|| 17 | '&origins=Kube-Pak+194+County+Rd+526,+Allentown,+NJ+08501'|| -- Use your address here 18 | '&destinations='|| trim(inDest) || 19 | '&key=InsertValidGoogleAPIKeyHere'; 20 | SELECT cast(int(trim(elementDistanceValue)) * 0.000621371 as numeric(7,2)) into outMiles 21 | FROM XMLTABLE('$doc/DistanceMatrixResponse' 22 | PASSING XMLPARSE(DOCUMENT SYSTOOLS.HTTPGETCLOB( GOOGLE_URL ,'') 23 | ) AS "doc" 24 | COLUMNS 25 | status VARCHAR(30) PATH 'status', 26 | origin_address VARCHAR(253) PATH 'origin_address', 27 | destination_address VARCHAR(256) PATH 'destination_address', 28 | elementStatus VARCHAR(3) PATH 'row/element/status', 29 | elementDurationValue VARCHAR(15) PATH 'row/element/duration/value', 30 | elementDurationText VARCHAR(15) PATH 'row/element/duration/text', 31 | elementDistanceValue VARCHAR(15) PATH 'row/element/distance/value', 32 | elementDistanceText VARCHAR(15) PATH 'row/element/distance/text' 33 | ) AS WebServiceResult; 34 | 35 | 36 | -- Set outMiles = cast(outMeters * 0.000621371 as numeric(7,2)); 37 | RETURN outMiles; 38 | END; 39 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQL-for-IBM-i-examples 2 | SQL samples that demonstrate IBM i's Db2 database capabilities 3 | 4 | Created 6 March 2018....in its baby stage. 5 | -------------------------------------------------------------------------------- /User_Statistics.sql: -------------------------------------------------------------------------------- 1 | -- This should work for 7.1 and above. Just some simple math to get a bead on user security statistics. 2 | -- The only DB2 for i Service it hits is QSYS2.USER_INFO. 3 | 4 | BEGIN 5 | -- Count total users 6 | DECLARE all_users DEC(7, 0); 7 | -- Users with Special Authorities 8 | DECLARE users_with_spcaut DEC(7, 0); 9 | DECLARE pct_users_with_spcaut DEC(5, 2); 10 | DECLARE users_with_splctl DEC(7, 0); 11 | DECLARE pct_users_with_splctl DEC(5, 2); 12 | DECLARE users_with_allobj DEC(7, 0); 13 | DECLARE pct_users_with_allobj DEC(5, 2); 14 | DECLARE users_with_jobctl DEC(7, 0); 15 | DECLARE pct_users_with_jobctl DEC(5, 2); 16 | DECLARE users_with_secadm DEC(7, 0); 17 | DECLARE pct_users_with_secadm DEC(5, 2); 18 | DECLARE users_with_audit DEC(7, 0); 19 | DECLARE pct_users_with_audit DEC(5, 2); 20 | DECLARE users_with_savsys DEC(7, 0); 21 | DECLARE pct_users_with_savsys DEC(5, 2); 22 | DECLARE users_with_iosyscfg DEC(7, 0); 23 | DECLARE pct_users_with_iosyscfg DEC(5, 2); 24 | DECLARE users_with_service DEC(7, 0); 25 | DECLARE pct_users_with_service DEC(5, 2); 26 | DECLARE users_with_pwdnone DEC(7, 0); 27 | DECLARE pct_users_with_pwdnone DEC(5, 2); 28 | DECLARE users_signon_90days DEC(7, 0); 29 | DECLARE pct_users_signon_90days DEC(5, 2); 30 | DECLARE users_signon_never DEC(7, 0); 31 | DECLARE pct_users_signon_never DEC(5, 2); 32 | DECLARE users_pwd_expired DEC(7, 0); 33 | DECLARE pct_users_pwd_expired DEC(5, 2); 34 | DECLARE users_pwd_none DEC(7, 0); 35 | DECLARE pct_users_pwd_none DEC(5, 2); 36 | DECLARE users_lmtcpl DEC(7, 0); 37 | DECLARE pct_users_lmtcpl DEC(5, 2); 38 | DECLARE users_disabled DEC(7, 0); 39 | DECLARE pct_users_disabled DEC(5, 2); 40 | DECLARE group_profiles_pwd DEC(7, 0); 41 | DECLARE pct_group_profiles_pwd DEC(5, 2); 42 | DECLARE users_pwd_expint DEC(7, 0); 43 | DECLARE pct_users_pwd_expint DEC(5, 2); 44 | SET all_users = (SELECT COUNT(AUTHORIZATION_NAME) 45 | FROM QSYS2.USER_INFO); 46 | SET users_with_spcaut = (SELECT COUNT(AUTHORIZATION_NAME) 47 | FROM QSYS2.USER_INFO 48 | WHERE SPECIAL_AUTHORITIES <> ''); 49 | SET pct_users_with_spcaut = (users_with_spcaut / all_users) * 100; 50 | SET users_with_splctl = (SELECT COUNT(AUTHORIZATION_NAME) 51 | FROM QSYS2.USER_INFO 52 | WHERE SPECIAL_AUTHORITIES LIKE '%*SPLCTL%'); 53 | SET pct_users_with_splctl = (users_with_splctl / all_users) * 100; 54 | SET users_with_allobj = (SELECT COUNT(AUTHORIZATION_NAME) 55 | FROM QSYS2.USER_INFO 56 | WHERE SPECIAL_AUTHORITIES LIKE '%*ALLOBJ%'); 57 | SET pct_users_with_allobj = (users_with_allobj / all_users) * 100; 58 | SET users_with_jobctl = (SELECT COUNT(AUTHORIZATION_NAME) 59 | FROM QSYS2.USER_INFO 60 | WHERE SPECIAL_AUTHORITIES LIKE '%*JOBCTL%'); 61 | SET pct_users_with_jobctl = (users_with_jobctl / all_users) * 100; 62 | SET users_with_secadm = (SELECT COUNT(AUTHORIZATION_NAME) 63 | FROM QSYS2.USER_INFO 64 | WHERE SPECIAL_AUTHORITIES LIKE '%*SECADM%'); 65 | SET pct_users_with_secadm = (users_with_secadm / all_users) * 100; 66 | SET users_with_iosyscfg = (SELECT COUNT(AUTHORIZATION_NAME) 67 | FROM QSYS2.USER_INFO 68 | WHERE SPECIAL_AUTHORITIES LIKE '%*IOSYSCFG%'); 69 | SET pct_users_with_iosyscfg = (users_with_iosyscfg / all_users) * 100; 70 | SET users_with_service = (SELECT COUNT(AUTHORIZATION_NAME) 71 | FROM QSYS2.USER_INFO 72 | WHERE SPECIAL_AUTHORITIES LIKE '%*SERVICE%'); 73 | SET pct_users_with_service = (users_with_service / all_users) * 100; 74 | -- users with Password as 75 | 76 | 77 | 78 | SET users_with_pwdnone = (SELECT COUNT(AUTHORIZATION_NAME) 79 | FROM QSYS2.USER_INFO 80 | WHERE NO_PASSWORD_INDICATOR = 'YES'); 81 | SET pct_users_with_pwdnone = (users_with_pwdnone / all_users) * 100; 82 | -- Users who havent signed on in 90 days 83 | SET users_signon_90days = (SELECT COUNT(AUTHORIZATION_NAME) 84 | FROM QSYS2.USER_INFO 85 | WHERE ADD_MONTHS(CURRENT_TIMESTAMP, -3) > 86 | PREVIOUS_SIGNON); 87 | SET pct_users_signon_90days = (users_signon_90days / all_users) * 100; 88 | -- Users who have never signed on 89 | SET users_signon_never = (SELECT COUNT(AUTHORIZATION_NAME) 90 | FROM QSYS2.USER_INFO 91 | WHERE PREVIOUS_SIGNON IS NULL); 92 | SET pct_users_signon_never = (users_signon_never / all_users) * 100; 93 | -- Users with password set to expired 94 | SET users_pwd_expired = (SELECT COUNT(AUTHORIZATION_NAME) 95 | FROM QSYS2.USER_INFO 96 | WHERE SET_PASSWORD_TO_EXPIRE = 'YES'); 97 | SET pct_users_pwd_expired = (users_pwd_expired / all_users) * 100; 98 | -- Users with password of *NONE 99 | SET users_pwd_none = (SELECT COUNT(AUTHORIZATION_NAME) 100 | FROM QSYS2.USER_INFO 101 | WHERE NO_PASSWORD_INDICATOR = 'YES'); 102 | SET pct_users_pwd_none = (users_pwd_none / all_users) * 100; 103 | SET users_lmtcpl = (SELECT COUNT(AUTHORIZATION_NAME) 104 | FROM QSYS2.USER_INFO 105 | WHERE LIMIT_CAPABILITIES = '*YES'); 106 | SET pct_users_lmtcpl = (users_lmtcpl / all_users) * 100; 107 | SET users_disabled = (SELECT COUNT(AUTHORIZATION_NAME) 108 | FROM QSYS2.USER_INFO 109 | WHERE STATUS = '*DISABLED'); 110 | SET pct_users_disabled = (users_disabled / all_users) * 100; 111 | SET group_profiles_pwd = (SELECT COUNT(AUTHORIZATION_NAME) 112 | FROM QSYS2.USER_INFO 113 | WHERE GROUP_ID_NUMBER <> 0 AND 114 | NO_PASSWORD_INDICATOR = 'NO'); 115 | SET pct_group_profiles_pwd = (group_profiles_pwd / all_users) * 100; 116 | SET users_pwd_expint = (SELECT COUNT(AUTHORIZATION_NAME) 117 | FROM QSYS2.USER_INFO 118 | WHERE PASSWORD_EXPIRATION_INTERVAL <> 0); 119 | SET pct_users_pwd_expint = (users_pwd_expint / all_users) * 100; 120 | --create the userstats table 121 | 122 | 123 | 124 | CREATE TABLE qtemp.userstats(description CHAR(75),amount INT,percent 125 | DEC(5, 2)); 126 | -- insert scripts 127 | INSERT INTO qtemp.userstats(description,amount) 128 | VALUES ('Total Users',all_users); 129 | INSERT INTO qtemp.userstats(description,amount,percent) 130 | VALUES 131 | ('Users with Special Authorities',users_with_spcaut,pct_users_with_spcaut); 132 | INSERT INTO qtemp.userstats(description,amount,percent) 133 | VALUES ('Users with *SPLCTL',users_with_splctl,pct_users_with_splctl); 134 | INSERT INTO qtemp.userstats(description,amount,percent) 135 | VALUES ('Users with *ALLOBJ',users_with_allobj,pct_users_with_allobj); 136 | INSERT INTO qtemp.userstats(description,amount,percent) 137 | VALUES ('Users with *JOBCTL',users_with_jobctl,pct_users_with_jobctl); 138 | INSERT INTO qtemp.userstats(description,amount,percent) 139 | VALUES ('Users with *SECADM',users_with_secadm,pct_users_with_secadm); 140 | INSERT INTO qtemp.userstats(description,amount,percent) 141 | VALUES ('Users with *IOSYSCFG',users_with_iosyscfg,pct_users_with_iosyscfg); 142 | INSERT INTO qtemp.userstats(description,amount,percent) 143 | VALUES ('Users with *SERVICE',users_with_service,pct_users_with_service); 144 | INSERT INTO qtemp.userstats(description,amount,percent) 145 | VALUES 146 | ('Users not signed-on in 90 days',users_signon_90days,pct_users_signon_90days); 147 | INSERT INTO qtemp.userstats(description,amount,percent) 148 | VALUES 149 | ('Users who have never signed on',users_signon_never,pct_users_signon_never); 150 | INSERT INTO qtemp.userstats(description,amount,percent) 151 | VALUES 152 | ('Users with password expired',users_pwd_expired,pct_users_pwd_expired); 153 | INSERT INTO qtemp.userstats(description,amount,percent) 154 | VALUES 155 | ('Users with password set to *NONE',users_pwd_none,pct_users_pwd_none); 156 | INSERT INTO qtemp.userstats(description,amount,percent) 157 | VALUES 158 | ('Users with limited capabilities set to *YES',users_lmtcpl,pct_users_lmtcpl); 159 | INSERT INTO qtemp.userstats(description,amount,percent) 160 | VALUES ('Disabled User Profiles',users_disabled,pct_users_disabled); 161 | INSERT INTO qtemp.userstats(description,amount,percent) 162 | VALUES 163 | ('Group profiles with passwords',group_profiles_pwd,pct_group_profiles_pwd); 164 | INSERT INTO qtemp.userstats(description,amount,percent) 165 | VALUES 166 | ('Users with password sysval override',users_pwd_expint,pct_users_pwd_expint); 167 | END; 168 | select * from qtemp.userstats; 169 | -------------------------------------------------------------------------------- /fishes.txt: -------------------------------------------------------------------------------- 1 | 2 | 3 | set schema "your schema name goes here"; 4 | drop table fishes ; 5 | create table fishes ( 6 | fish_name for column name char( 10 ) not null default 7 | ,fish_color for column color char(10) not null default 8 | ,fish_weight for column weight int not null default 9 | ); 10 | alter table fishes add primary key ( name ); 11 | alter table fishes add constraint cst_color check ( name<>color ); 12 | 13 | insert into fishes values('haddock' ,'white', 1); 14 | insert into fishes values('cod' ,'green', 2); 15 | insert into fishes values('hake' ,'yellow', 3 ); 16 | insert into fishes values('mackerel','blue', 4 ); 17 | insert into fishes values('tench' ,'orange', 5 ); 18 | insert into fishes values('sprat' ,'purple', 6 ); 19 | insert into fishes values('dace' ,'fuscia',7 ); 20 | insert into fishes values('rudd' ,'maroon',8 ); 21 | insert into fishes values('pike' ,'plum', 9 ); 22 | insert into fishes values('gudgeon' ,'lilac',10); 23 | insert into fishes values('white' ,'white', 11 ); -- violates check constraint CST_COLOR gives error SQL State: 23513 24 | insert into fishes values('haddock' ,'magenta', 12); -- violates unique constraint gives error SQL State: 23505 25 | select * from fishes order by color ;; 26 | 27 | 28 | -- Common table expression 29 | 30 | with a as 31 | ( select row_number() over(order by order of f) - 1 as nb, 32 | name as name 33 | from fishes as f 34 | ), b as 35 | ( select smallint(nb/5)+1 as outrow, 36 | smallint(mod(nb,5))+1 as outcol, 37 | name as name 38 | from a 39 | ), c as 40 | ( select outrow, 41 | (case when outcol=1 then name else null end) as name1, 42 | (case when outcol=2 then name else null end) as name2, 43 | (case when outcol=3 then name else null end) as name3, 44 | (case when outcol=4 then name else null end) as name4, 45 | (case when outcol=5 then name else null end) as name5 46 | from b 47 | ) 48 | select outrow, 49 | max(name1) col_1, 50 | max(name2) col_2, 51 | max(name3) col_3, 52 | max(name4) col_4, 53 | max(name5) col_5 54 | from c 55 | group by outrow 56 | order by outrow ; 57 | 58 | /* 59 | The first step gives you an intermediate result of 60 | 61 | rn fish 62 | ====== ========== 63 | 0 haddock 64 | 1 cod 65 | 2 hake 66 | 3 mackerel 67 | 4 tench 68 | 5 sprat 69 | 6 dace 70 | 7 rudd 71 | 8 pike 72 | 9 gudgeon 73 | 74 | The next step gives 75 | 76 | outrow outcol fish 77 | ====== ====== ========== 78 | 1 1 haddock 79 | 1 2 cod 80 | 1 3 hake 81 | 1 4 mackerel 82 | 1 5 tench 83 | 2 1 sprat 84 | 2 2 dace 85 | 2 3 rudd 86 | 2 4 pike 87 | 2 5 gudgeon 88 | 89 | Then we spread the values out to separate columns based on the column number 90 | 91 | outrow fish1 fish2 fish3 fish4 fish5 92 | ====== ======== ======== ======== ======== ======== 93 | 1 haddock 94 | 1 cod 95 | 1 hake 96 | 1 mackerel 97 | 1 tench 98 | 2 sprat 99 | 2 dace 100 | 2 rudd 101 | 2 pike 102 | 2 gudgeon 103 | 104 | The last step squeezes the rows together by outrow number 105 | 106 | outrow col_1 col_2 col_3 col_4 col_5 107 | ====== ======== ======== ======== ======== ======== 108 | 1 haddock cod hake mackerel tench 109 | 2 sprat dace rudd pike gudgeon 110 | */ --------------------------------------------------------------------------------