× 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.


  • Subject: Re: Reading the results of a stored procedure with a UDTF and/or a view.
  • From: Buck Calabro <kc2hiz@xxxxxxxxx>
  • Date: Wed, 13 Feb 2019 10:56:07 -0500
  • Autocrypt: addr=kc2hiz@xxxxxxxxx; keydata= mQGiBEcbaT4RBADqmM9OgXil65pjrxclJpxuAF6vraI3kkmJbEHb5ElL7EquHE3QDuFqFgIB 4NZLHDbVAh0AD5exAX+r+xg//UvtBc2k34HROnCpWTMnIOaSVhhVjpYEbZGLz6wfrRpu4Qyn 45iaKT4F0qcHo+0LrGQPef3xrFkUhxURgzY5zgo6+wCg/XjYJ155witPWB2CbNf6RAm9QT0D /jSp6YhvE3xPE12aBuRYM678JTbaQfuYv4HUfug1Wz/0zH5btfEihWVN4wbKaoQ/H/29v2TP /Lyh8XTVd3Z0rz4iaSD5fGicn81WPANBeIepLB8vpfEik6UhHpN1DJkz6Ryw2mgx8p53LhHV Ck4Jt0HP2TAl3f7QTXGFOiFzJwEqBACsHk/gFpKAHdv7n4vJoHqp0RNgOOyhnTThlulPilt6 tAaSe10FOrrugBuLMn7wXBANQ1ApmIb5yNjhYqPREj65OVv2MUbw8H2HnQs//Z6aodyR/kzU 2q2G9A/YFI1LL0m/gvaVbEj/wE0ybBgFkrcoEFeStkqS5HzLEFGUDFXhD7QfQnVjayBDYWxh YnJvIDxrYzJoaXpAZ21haWwuY29tPoiFBBMRAgBFAhsDBgsJCAcDAgQVAggDBBYCAwECHgEC F4AFAkcbdMokGGh0dHA6Ly9rZXlzZXJ2ZXIudmVyaWRpcy5jb206MTEzNzEvAAoJEN7KcclH umuRfngAoNXU6AXqyTR8FRuoXKBGS4k7bPUEAJ912WKSkjpCt0axjrq6j22e5XgWzbkCDQRH G2k+EAgAnLXJ9hOqedgsIYM3LuomBBNN+7WTFSVaJ3Rqz8XVZtJvLL0bIRAvpVK9L9rYXlCR cPAm0YNK6H2DR7sQxWlxEH4mWB+jTCTALpcVq+Kpfbw5qDdn+9DVMS7tBOchtTlPSGgdKgn7 sTObra8cHtX/ddTB6OLzHeTXr4PZbUwVeQdIStdwMmozKBQvgjXWKi1GiuYbwYkCM/zJEUCs J36BIE4li9xohJ5O4iKC20YVckMJfZLbn1a2gVgn6Re8C5ezNewT0qM8ZDCUNENWAxsU/c9J UCFQ2QcMU+25b84D5yPxnEKna5U9Fz2JjRjWy5ZKZx2+WhZj0r2Tw6/kGb28AwADBgf/WBsn JSMHxyVfg+LKLHpdANwa9jdrKOt2WjJbWOiJ9l7SmqD0oi3c22FFxRXKsFfjCikLk9wbLZKH SqqnOePvMMHqNcqQTSv7+ARjxnBH4g6dhqg+zmebKpt8zV2awQzYSSm4YY6IqzkWmPNAN7BU zUtSAfL4UU2PljTnT9m443aVCTXMne5l90HQv/gdJ121owg5KuGE6LodTpoR4hn9nbdKWtfY pDNoykvR+GN5y335yF2Zp/j6QgdxWezjou5Y3/6PUZLEsJagWe9hAcKb1eiO2bmg+1bFYu0T g5Mvb27nqfFeHHFysC7a7sXtxp/pqNLNDcK6j/7Th6vF7/n98YhJBBgRAgAJBQJHG2k+AhsM AAoJEN7KcclHumuR9SgAnRuJWHon4GP58xbqCiFR/jSUfvRgAJ47KZ1UNoXgdftoePnbrZu6 W+poEw==
  • List-archive: <https://archive.midrange.com/midrange-l/>
  • List-help: <mailto:midrange-l-request@lists.midrange.com?subject=help>
  • List-id: Midrange Systems Technical Discussion <midrange-l.lists.midrange.com>
  • List-post: <mailto:midrange-l@lists.midrange.com>
  • List-subscribe: <https://lists.midrange.com/mailman/listinfo/midrange-l>, <mailto:midrange-l-request@lists.midrange.com?subject=subscribe>
  • List-unsubscribe: <https://lists.midrange.com/mailman/options/midrange-l>, <mailto:midrange-l-request@lists.midrange.com?subject=unsubscribe>

On 2/13/2019 7:26 AM, Rob Berendt wrote:

My question then becomes "Is it possible to make a general UDTF to wrap around qsys2.DISPLAY_JOURNAL_ENTRY_INFO?".

I took a stab at an all-SQL solution (auditors are happy) and ended up
using a pipelined function. It has one tremendous disadvantage: one
needs to declare the columns of the returned table in advance. So... not
generic. The good news is that one can specify a subset of columns; it
doesn't need to be every column in the journalled table.

I post it in the hopes that someone else will get an aha!



create or replace function opensource.dspjrndta (
journal_lib_in char(10),
journal_name_in char(10),
table_lib_in char(128),
table_name_in char(128),
table_mbr_in char(10),
user_name_in char(10)
)
returns table (
sequence_number int,
journal_code char(10),
program_name char(10),
program_library char(10),
receiver_name char(10),
receiver_library char(10),
rs_col1 char(3),
rs_col2 char(9),
rs_col3 char(3),
rs_col4 char(24),
rs_col5 char(27)
-- ...
)
deterministic
modifies sql data

set option commit = *NONE

--
begin

declare journal_code char(10);
declare receiver_name char(10);
declare receiver_library char(10);
declare sequence_number int;
declare rs RESULT_SET_LOCATOR varying;

declare rs_col1 char(3);
declare rs_col2 char(9);
declare rs_col3 char(3);
declare rs_col4 char(24);
declare rs_col5 char(27);

-- cursor of journal entries
for je cursor for

SELECT X.*
FROM TABLE (
QSYS2.Display_Journal(
journal_lib_in, journal_name_in,
OBJECT_LIBRARY=>table_lib_in, OBJECT_NAME=>table_name_in,
OBJECT_OBJTYPE=>'*FILE', OBJECT_MEMBER=>table_mbr_in
) ) AS X
WHERE journal_entry_type in ('DL', 'PT', 'PX', 'UP')
AND "CURRENT_USER" = user_name_in
ORDER BY entry_timestamp DESC
for read only
do
-- 'translate' the entry_data into a row
call qsys2.display_journal_entry_info(2,
journal_lib_in,
journal_name_in,
sequence_number,
receiver_library,
receiver_name,
journal_code
);

associate result set locators (rs)
with procedure qsys2.display_journal_entry_info;

allocate jedetails cursor for result set rs;

-- each column needs to be specified here, and declared
-- above, in the 'return table' clause, and also
-- each one needs to be declared the proper type and size, too.
fetch jedetails into rs_col1, rs_col2, rs_col3, rs_col4, rs_col5;

pipe(sequence_number, journal_code, program_name, program_library,
receiver_name, receiver_library,
rs_col1, rs_col2, rs_col3, rs_col4, rs_col5);

close jedetails;

end for;

return;

--
end;




As an Amazon Associate we earn from qualifying purchases.

This thread ...

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.