|
The sysprocs and sysroutines tables/views have a column that stores the
original sql creation statement.
Use a select statement with the where routine_name = 'myroutine_name'.
El vie, 9 ago 2024 a las 9:33, Greg Wilburn (<
gwilburn@xxxxxxxxxxxxxxxxxxxxxxx>) escribió:
Birgitta,use
This is a function... I am using it in an SQL Select statement within an
SQL view - selecting it like field.
SELECT
DFT_WHS,
CLT.COM_NBR,
CLT.COM_NAME,
WHS_NBR,
RF.PICKER,
RF.STD_LPH,
RF.RDS_LPH,
ODORD# AS ORD_NBR,
ODREL# AS REL_NBR,
COUNT(ODCTT#) AS LINES,
PIK_DATE,
PIK_TIME,
ASTHHOBJ.TBF_SHIPBYDATE(PIK_DATE,
PIK_TIME,PTY_CODE),
PTY_CODE,
PTY_DESC
FROM...
I created this function years ago (maybe 8 or 9).
It references an RPG procedure (TBF_ShipbyDate) in a SRVPGM called
TBFUTILR4
This procedure calls another procedure inside the same SRVPGM which uses
SQL
My problem is that I cannot find any reference to it on our system - even
though it is still functioning.
I hesitate to re-create it for fear of breaking it, and the views that
it.midrange-l@xxxxxxxxxxxxxxxxxx
Is there a way to "recover" the SQL statement that created the function?
Thx,
Greg
-----Original Message-----
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of
Birgitta Hauser
Sent: Friday, August 9, 2024 11:10 AM
To: 'Midrange Systems Technical Discussion' <
ItSubject: RE: Help with SQL Procedure
You have to register your RPG-Function as an external Function.But I cannot find anything using the Database Management tool in ACS.
Something like this:
CREATE OR REPLACE FUNCTION ASTHHOBJ.TBF_SHIPBYDATE (
PARDATE DATE ,
PARTIME TIME,
PARCODE VARCHAR(3))
RETURNS DATE
LANGUAGE RPGLE
SPECIFIC YOURNAME
EXTERNAL NAME 'YOURLIB/YOURSRVPGM(YOURRPGFUNCTION)' ;
BTW in SQL there is a difference between Function and Procedure.
A (stored) procedure can have input and output parameters and return a
result set, but must be called with the SQL CALL Statement.
A (user defined) function has a return value and only input parameters.
can be called within a SQL Select-Statement or INSERT, UPDATE, DELETE ...is
like any scalar function.
Mit freundlichen Grüßen / Best regards
Birgitta Hauser
Modernization - Education - Consulting on IBM i Database and Software
Architect IBM Champion since 2020
"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok) "What
worse than training your staff and losing them? Not training them andRPG
keeping them!"
"Train people well enough so they can leave, treat them well enough so
they don't want to. " (Richard Branson) "Learning is experience ...
everything else is only information!" (Albert
Einstein)
-----Original Message-----
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of
Greg Wilburn
Sent: Friday, 9 August 2024 16:32
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxxxxxxxx
Subject: Help with SQL Procedure
I'm losing my mind...
I have an SQL view that references a procedure (function) in one of my
service programs. I'm fairly certain at some point I had to create anSQL
procedure/function to access the RPG function from within a view. But Isubscribe,
cannot find anything using the Database Management tool in ACS.
Shouldn't I be able to find an SQL Procedure or Function in the same
library?
One of the columns selected in my view is
ASTHHOBJ.TBF_SHIPBYDATE(PIK_DATE, PIK_TIME,PTY_CODE),
This returns a Date based on the parameters passed in.
Even if I click on "All Database Objects" in this library, I do not see
anything named "TBF_SHIPBYDATE".
My user profile has *ALLOBJ authority (I would have created the objects
anyway)
I can see the procedure referenced when I regenerate the SQL source from
the view object.
I tried RCLDBXREF OPTION(*FIX) for that library (as Charles suggested in
the RPG group).
What am I missing?
TIA,
Greg
[Logo]<https://www.totalbizfulfillment.com/> Greg Wilburn
Director of IT
301.895.3792 ext. 1231
301.895.3895 direct
gwilburn@xxxxxxxxxxxxxxxxxxxxxxx<mailto:gwilburn@xxxxxxxxxxxxxxxxxxxxxxx
1 Corporate Dr
Grantsville, MD 21536
www.totalbizfulfillment.com<http://www.totalbizfulfillment.com>
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing
list To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx To
unsubscribe, or change list options,subscribe,
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.
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing
list To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx To
unsubscribe, or change list options,list
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.
Greg Wilburn
Director of IT
301.895.3792 ext. 1231
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing
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.
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.
As an Amazon Associate we earn from qualifying purchases.
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.