Hi,
SQL naming convention versus System naming convention, you may find the
following 2 articles helpful:
System versus SQL naming convention : Part 1
Object authority and privileges for SQL database objects
http://www.ibm.com/developerworks/ibmi/library/i-sqlnaming/index.html
System versus SQL naming convention: Part 2
Accessing database objects
http://www.ibm.com/developerworks/ibmi/library/i-system_sql2/index.html
Mit freundlichen Grüßen / Best regards
Birgitta Hauser
"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 is worse than training your staff and losing them? Not training them
and keeping them!"
-----Ursprüngliche Nachricht-----
Von: midrange-l-bounces@xxxxxxxxxxxx
[mailto:midrange-l-bounces@xxxxxxxxxxxx] Im Auftrag von Needles,Stephen J
Gesendet: Thursday, 25.4 2013 22:51
An: Midrange Systems Technical Discussion
Betreff: RE: SQL UDF...why do i need to qualify the UDF and the tablebeing
used?
Thank you Chuck!
I deleted and re-created everything, meticulously following what you had
described. And it works!
The weird thing is...I thought that that was what I'd done in the first
place! Before I started going through all of the gyrations with changing o
*SQL and everything. I wonder what stray thought lead me down the wrong
path.
Thanks again Chuck!
Steve Needles
Northland Insurance - A Travelers Company
385 Washington Street, SB03N
St. Paul, MN 55102
Tel: 651-310-4203
sneedles@xxxxxxxxxxxxx
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx
[mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of CRPence
Sent: Thursday, April 25, 2013 3:28 PM
To: midrange-l@xxxxxxxxxxxx
Subject: Re: SQL UDF...why do i need to qualify the UDF and the table being
used?
On 25 Apr 2013 12:14, Needles,Stephen J wrote:
<<SNIP>>
CREATE FUNCTION library.MaxSEQupv
<<SNIP>>
BEGIN
RETURN(
select ...
from library.table
...
);
END
In order to get it to work, I needed to qualify the table. I would
prefer to make this schema independent.
Unqualified, the identifier should have been the authorization ID, the
user profile name, when using NAMING(*SQL).
I tested using:
select
library.MAXSEQUPV(cast('3434343434' as char(10)) , cast(20120301 as
decimal(8,0))) from sysibm.sysdummy1
again...in order to get it to work, I had to change over to *SQL
rather than *SYS for naming conventions and had to qualify the UDF.
Again, I would prefer to make the UDF schema independent.
What have I done wrong?
Whatever interface was being used to issue the CREATE FUNCTION was not
noted. But if the UDF is created using NAMING *SYS, then the default PATH
will be *LIBL and the Library List will be utilized to locate unqualified
identifiers which are table-references... as long as there is no CURRENT
SCHEMA set.
After the UDF is created, use PRTSQLINF to see the PATH and SCHEMA
settings that were in effect.
The following issued with NAMING(*SYS) active in the SQL environment
being used to issue the CREATE, and no /current schema/ being set [via
whatever is the parameter specification on the feature being utilized to
issue the SQL CREATE FUNCTION, that equate with that special register]
should offer what is desired; i.e. allow unqualified table reference, and
unqualified function reference, when using System Naming and the default
Path:
CREATE FUNCTION library/MaxSEQupv
( parm1 char(10)
, parm2 dec(8, 0)
) RETURNS dec(3, 0)
LANGUAGE SQL
RETURN(
select
cast(max(field3) as decimal(3, 0))
from /* no qualifier */ table
where field1 = parm1
and field2<= parm2
)
FWiW the above request drops the BEGIN and END because there is only one
statement, the RETURN. That source is now compatible also when the decimal
separator is a comma.
--
Regards, Chuck
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx To subscribe, unsubscribe,
or change list options,
visit:
http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx Before posting, please take a
moment to review the archives at
http://archive.midrange.com/midrange-l.
________________________________
This communication, including attachments, is confidential, may be subject
to legal privileges, and is intended for the sole use of the addressee. Any
use, duplication, disclosure or dissemination of this communication, other
than by the addressee, is prohibited. If you have received this
communication in error, please notify the sender immediately and delete or
destroy this communication and all copies.
TRVDiscDefault::1201
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx To subscribe, unsubscribe,
or change list options,
visit:
http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx Before posting, please take a
moment to review the archives at
http://archive.midrange.com/midrange-l.
As an Amazon Associate we earn from qualifying purchases.