× The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.



Perhaps a compound statement is more easy to understand:

create schema XXXXXXXX;
set schema XXXXXXXX;

CREATE OR REPLACE TABLE XXXXXXXX.srctbl (
Yr INTEGER NOT NULL
,qtr INTEGER not null
,dta CHAR(5)
);

INSERT INTO XXXXXXXX.srctbl
VALUES
(2020,1,'Bob' )
,(2020,1,'Sam' )
,(2020,2,'Fred' )
,(2020,2,'Dog' )
,(2021,2,'Cat' )
;

begin
declare table_name varchar(32);

for select distinct Yr, qtr from XXXXXXXX.srctbl do
set table_name = 'TBL_' || yr || '_' || qtr;
execute immediate 'create or replace table ' || table_name || '
like XXXXXXXX.srctbl';
execute immediate 'insert into ' || table_name || ' select * from
XXXXXXXX.srctbl where yr=' || yr || ' and qtr=' || qtr ;
end for;
end;

select * from systables where table_schema = 'XXXXXXXX';
select * from TBL_2020_1

On Mon, Dec 13, 2021 at 1:18 AM Sam_L <lennon_s_j@xxxxxxxxxxx> wrote:

I would probably do this with a combination of SQL and CLP, not RPG.

But since SQL can run CL commands, it can also be done in just SQL.
Something like the below where XXXXXXXX is your library. (The CTEs make
debugging it easier.)

-- Create some test data
CREATE OR REPLACE TABLE XXXXXXXX.srctbl (
Yr INTEGER NOT NULL
,qtr INTEGER not null
,dta CHAR(5)
);
INSERT INTO XXXXXXXX.srctbl
VALUES
(2020,1,'Bob' )
,(2020,1,'Sam' )
,(2020,2,'Fred' )
,(2020,2,'Dog' )
,(2021,2,'Cat' )
;

-- Now split everything up by year and quarter
with tbls as
(
select distinct Yr, qtr from XXXXXXXX.srctbl
)
, t_names as
(
select 'TBL_' || trim(char(yr)) || '_'
|| trim(char(qtr)) as tbl_name
, t.* from tbls t
)
, cmds as
(
select
'create table '
|| tbl_name
|| ' as (select * from XXXXXXXX.srctbl) '
|| ' with no data'
as crt_tbl,
'insert into XXXXXXXX.'
|| tbl_name
|| ' (select * from XXXXXXXX.srctbl where yr=' || yr
|| ' and qtr=' || qtr || ')'
as ins_tbl
from t_names
)
, execs as
(
select
('runsql sql(''' ||crt_tbl) ||''') commit(*none) naming(*sql)'
as do_crt,
('runsql sql(''' ||ins_tbl) ||''') commit(*none) naming(*sql)'
as do_ins
from cmds c
)
select
QSYS2.QCMDEXC(do_crt),
QSYS2.QCMDEXC(do_ins)
from execs
;
-- Check results
select * from XXXXXXXX.tbl_2020_1;

You could put this in a source member and run it with RUNSQLSTM. For
extra credit you could change the do_ins to be a submit job and have
several inserts run in parallel.

Or if you don't like the SQL you could reconstruct in a CL program.

Sam

On 12/10/2021 11:00 AM, K Crawford wrote:
I have a table with several columns that I want to split into several
tables.
My source table example:
SrcTbl
Year qtr data
2020 1 bob
2020 1 sam
2020 2 fred
2020 2 dog
2021 2 cat

What I want would be three tables.
tbl_2020_1
2020 1 bob
2020 1 sam
tbl_2020_2
2020 2 fred
2020 2 dog
tbl_2021_2
2021 2 cat

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives
at https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription related
questions.

Help support midrange.com by shopping at amazon.com with our affiliate
link: https://amazon.midrange.com


As an Amazon Associate we earn from qualifying purchases.

This thread ...

Follow-Ups:
Replies:

Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].

Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.