IF ISCLEAR(lADOConnection) THEN CREATE(lADOConnection); lADOConnection.ConnectionString:=GetConnectionString(precDBServer."Server Name", precDBServer."Database Name", precDBServer.Login, precDBServer.Password); lADOConnection.Open;LADOConnection is an automation variable of the type "'Microsoft ActiveX Data Objects 2.8 Library'.Connection". You also see that I compose my connectionstring in a seperate function:
GetConnectionString(...) : Text[1024] ltxtConnectionString:='Driver={SQL Server};' + 'Server='+pcodServerName+';' + 'Database='+pcodDatabaseName+';' + 'Uid='+pcodUserID+';' + 'Pwd='+pcodPassword+';'; EXIT(ltxtConnectionString);
lADOConnection.Close; CLEAR(lADOConnection);
CREATE PROCEDURE [dbo].[SP_CreateView_ItemLocation] @CompanyName VARCHAR(30) AS BEGIN SET NOCOUNT ON; DECLARE @SQLString NVARCHAR(MAX) --If the view already exists, drop the view SET @SQLString = 'IF OBJECT_ID (''['+@CompanyName+'$SP_ItemLocation]'', ''view'') IS NOT NULL DROP VIEW ['+@CompanyName+'$SP_ItemLocation]' EXEC sp_executesql @SQLString --assemble the SQLString (including the companyname) SET @SQLString = 'CREATE VIEW [dbo].['+@CompanyName+'$SP_ItemLocation] AS SELECT DISTINCT ''ILE'' AS TableName, [Item No_] AS ItemNo, [Location Code] AS LocationCode, ['+@CompanyName+'$Location].Name AS LocationName, ['+@CompanyName+'$Location].[Main Location] AS MainLocation FROM dbo.['+@CompanyName+'$Item Ledger Entry], ['+@CompanyName+'$Location] where dbo.['+@CompanyName+'$Item Ledger Entry].[Location Code] = ['+@CompanyName+'$Location].Code' print @SQLString --this "print " is optionally - it is useful when you're debugging your SP --in SSMS, because it shows the SQLString that you have been building. exec sp_executesql @SQLString ENDThen, I wrote some C/AL to call this SP (I excluded the connection-stuff mentioned above. Note that a connection is still necessary):
CreateCompanyViews() ... <Open your connection here (see above)> IF ISCLEAR(lADOCommand) THEN CREATE(lADOCommand); lvarActiveConnection := lADOConnection; lADOCommand.ActiveConnection := lvarActiveConnection; lADOCommand.CommandText := 'SP_CreateView_ItemLocation'; lADOCommand.CommandType := 4; lADOCommand.CommandTimeout := 0; lADOParameter:=lADOCommand.CreateParameter('@CompanyName', 200, 1, 30,COMPANYNAME); lADOCommand.Parameters.Append(lADOParameter); lADOCommand.Execute; ... <Close your connection here (see above)>You see that I'm using LADOCommand, which is an automation variable of the type "'Microsoft ActiveX Data Objects 2.8 Library'.Command" and LADOParameter is a "'Microsoft ActiveX Data Objects 2.8 Library'.Parameter". Some explanation is required, I guess:
cduMyADOSamplesMgt.CreateCompanyViews;I added this after the COMMIT, because I want to make sure that my company is created, no matter if my view was successfully created or not.
CREATE PROCEDURE [dbo].[SP_LoadInventory] @ItemNo AS VARCHAR(20) AS BEGIN SET NOCOUNT ON; DECLARE @CompanyName VARCHAR(30) DECLARE @OrigCompanyName VARCHAR(30) DECLARE @SQLString NVARCHAR(MAX) DECLARE @Counter INT DECLARE curCompany CURSOR FOR SELECT [Name] as CompanyName from dbo.Company OPEN curCompany SET @Counter = 0 SET @SQLString='' FETCH NEXT FROM curCompany INTO @CompanyName -- Begin looping all companies in the database WHILE @@FETCH_STATUS = 0 BEGIN -- Converting the wonderful NAV-supported-but-best-not-used-in-SQL characters SET @OrigCompanyName = @CompanyName SET @CompanyName = REPLACE(@CompanyName,'.','_'); SET @CompanyName = REPLACE(@CompanyName,'"','_'); SET @CompanyName = REPLACE(@CompanyName,'\','_'); SET @CompanyName = REPLACE(@CompanyName,'/','_'); SET @CompanyName = REPLACE(@CompanyName,'''','_'); -- Only put the UNION in between of two SELECT statements IF @Counter > 0 BEGIN SET @SQLString = @SQLString + 'UNION' END SET @SQLString = @SQLString + ' SELECT DISTINCT ''' + @OrigCompanyName + ''' AS CompanyName,ItemNo, LocationCode, LocationName, MainLocation FROM dbo.[' + @CompanyName + '$SP_ItemLocation] a WHERE ItemNo = ''' + @ItemNo + ''' ' FETCH NEXT FROM curCompany INTO @CompanyName SET @Counter = @Counter + 1 END; print @SQLString EXEC sp_executesql @SQLString CLOSE curCompany DEALLOCATE curCompany ENDThis is just a simple stored procedure that is going to UNION a SQL Statement for each company. In C/AL, you can call this Stored Procedure like:
... <Open your connection here> IF ISCLEAR(lADOCommand) THEN CREATE(lADOCommand); lvarActiveConnection := lADOConnection; lADOCommand.ActiveConnection := lvarActiveConnection; lADOCommand.CommandText := 'SP_LoadInventory'; lADOCommand.CommandType := 4; lADOCommand.CommandTimeout := 0; lADOParameter:=lADOCommand.CreateParameter('@ItemNo', 200, 1, 20,pcodItemNo); lADOCommand.Parameters.Append(lADOParameter); lADOCommand.Execute; IF ISCLEAR(lADORecordset) THEN CREATE(lADORecordset); lADORecordset.ActiveConnection := lvarActiveConnection; lADORecordset.Open(lADOCommand); WHILE NOT lADORecordset.EOF DO BEGIN ptmpGlobalInventoryBuffer.INIT; ptmpGlobalInventoryBuffer."Item No" := lADORecordset.Fields.Item('ItemNo').Value; ptmpGlobalInventoryBuffer."Company Name" := lADORecordset.Fields.Item('CompanyName').Value; ptmpGlobalInventoryBuffer."Location Code" := lADORecordset.Fields.Item('LocationCode').Value; ptmpGlobalInventoryBuffer."Location Name" := lADORecordset.Fields.Item('LocationName').Value; ptmpGlobalInventoryBuffer."Main Location" := lADORecordset.Fields.Item('MainLocation').Value; ptmpGlobalInventoryBuffer.INSERT; lADORecordset.MoveNext; END; ... <Close your connection here>May be here also some explanation:
CREATE PROCEDURE [dbo].[WALDO_test] @Result AS VARCHAR(20) OUTPUT AS BEGIN SET @Result = 'Test Output'; ENDYou define your outputparameter with the OUTPUT keyword.
... <Open your connection here> IF ISCLEAR(lADOCommand) THEN CREATE(lADOCommand); lvarActiveConnection := lADOConnection; lADOCommand.ActiveConnection := lvarActiveConnection; lADOCommand.CommandText := 'WALDO_test'; lADOCommand.CommandType := 4; lADOCommand.CommandTimeout := 0; lADOParameter:=lADOCommand.CreateParameter('@Result', 200, 2, 20,ltxtResult); lADOCommand.Parameters.Append(lADOParameter); lADOCommand.Execute; //Get your result back from the command variable : ltxtResult := FORMAT(lADOCommand.Parameters.Item('@Result').Value); MESSAGE(ltxtResult); ... <Close your connection here>You see that you need an extra statement to pull your result back from the command variable. It's not going to do that for you automatically (allthough you defined your parameter as being "output" (we defined the direction-argument in the CreateParameter-statement as "2")).
Comments
Can you explain about PrecDBServer.Is it variable or something.
please give reply i need it. :shock:
Microsoft Dynamics Nav
---You are the Creator of our own Destiny
precDBServer is a recordvariable of a table with the fields:
- "Code"
- "Description"
- "Server Name"
- "Database name"
- "Login"
- "Password"
So, it's a table which contains the connection details of servers. Using these fields, I can form a connectionstring.
Is that somewhat clear :?:
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
While i was trying to make connection , I got the following error.
can u help me .
Microsoft Business Solutions-Navision
This message is for C/AL programmers:
The call to member Open failed. Microsoft OLE DB Provider for ODBC Drivers returned the following message:
[Microsoft][ODBC SQL Server Driver][Shared Memory]SQL Server does not exist or access denied.
OK
I gave valid servername ,userid,password,database name.
but i don't know why it is showing this error.actually this was the code which i have written.
IF ISCLEAR(ladoconnection) THEN CREATE (ladoconnection);
ladoconnection.ConnectionString:=getconnectionstring(precdbserver."server name", precdbserver."database name", precdbserver.login,precdbserver.password);
ladoconnection.Open;
getconnectionstring(VAR server1 : Text[300];VAR databasename : Text[300];VAR login : Text[300];VAR password : Text[300]) ltextconnectio
ltextconnectionstring:='Driver={SQL Server};'
+ 'Server='+ server1 +';'
+ 'Database='+databasename+';'
+ 'Uid='+login+';'
+ 'Pwd='+password+';';
EXIT(ltextconnectionstring);
Microsoft Dynamics Nav
---You are the Creator of our own Destiny
Thanks =D>
Rajesh Patel
This is very interesting and useful. I have it working fine.
However, I can not get it to work, when the Stored Porcedure is made with an output parameter as this:
This is how I'm setting up parameters and doing the execution:
Of course the open connection and other stuff are working. The only thing, I can't figure out, is the line:
I've tried a lot of possibilities. But I'm getting confused understanding the setup of SQL data types.
I believe that the error
An exeption was raised in method Append. The OLE control or Automation server has returned error (HRESULT) -2147352567. The component did not provide the exception description.
is because data type mismatch. But how do I set the _ADOParameter to hold a float(53)? To change the SPs parameter data type has impact on other systems, so it is not easy to do this.
I'm used to code NAV but not SQL.
John Reinhold
And did you try it without setting the size ? Or by setting 53 as size?
Or something like
_ADOParameter := _ADOCommand.CreateParameter('@return_value_argument2',5,2,53,decMyResultParameter);
Or, if possible, change the float to a text or decimal, which is (more) compliant to C/SIDE?
Just a few ideas from the top of my head... :-k
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
It's a great idea to use the "tiers" part of SQL to generate the data via stored procedure..
With your approach, do you think it's possible (and relevant) to read what the stored procedure is sending back, in an instream to be treated in an xmlport??
With stored procedure, you can send back XML by using the FORXML statement.. It's not a recordset anymore and I don't know how to get it back, but it's valid xml.
ideas:?: :?: :?: :?:
Your post is very interesting thank
I try to make one connection with ado but I meet some problem:
I have one sql database with 4 record inside and I want to put this 4 record in one temporary Navision table. I try to follow your instruction, but when I execute my code only the first record is put i my Navision table. I made a LADORecordset.RecordCount(); and Navision show me -1 ???? ](*,)
I don't know if my T-sql or my navision code is wrong.
My T-sql
My nav code
Do you have any idea about the problem???
I think, if you just put "select Dossier from [dbo].[tableVendor]" in your SP would do the trick.
Also, you can avoid using an SP and just use the select statement as commandtext (and off course another command type (1)).
Didn't test this though ... good luck.
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
Thank you very much
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
in a previous message you say:
Also, you can avoid using an SP and just use the select statement as commandtext (and off course another command type (1)).
Is there any good documentation for this? I am updating a third party SQL database from Navision. I have it working (thanks for your help), using SP's I created in that SQL database. But I would prefer to not have to do anything in the other product just keep all the code in Navision.
I would need to do a SELECT and if the COUNT(*) is 0, do an INSERT.
When I try to do the SELECT statement using command type 1, I get errors...
Any help would be greatly appreciated.
Kelly
So in that case, I would choose for an SP... .
But May be if you return it into e recordset, read the first value of the first column (that should be your count(*))?
Can you put your code here?
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
My first issue is when I create a variable for a record set I get an error.
"The variable LADORECORDSET::WILLCHANGERECOR is defined more than once. An example could be: 'File' exists as both a data type and a global variable."
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
Sorry, not sure how to explain all this, here is my code.
If I remove the code between the asterisks and the variable lADORecordset, I can run the codeunit without errors.
Hopefully this will be more helpful :?:
//CREATE CONNECTION AND OPEN
IF ISCLEAR(lADOConnection) THEN
CREATE(lADOConnection);
lADOConnection.ConnectionString:= 'Driver={SQL Server}; Server=MDR-LAB; Database=WaspTrackAsset; UID=kw; PWD=kw';
lADOConnection.Open;
IF ISCLEAR(lADOCommand) THEN
CREATE(lADOCommand);
lvarActiveConnection := lADOConnection;
lADOCommand.ActiveConnection := lvarActiveConnection;
//GET RECORD SET
lADOCommand.CommandText := 'SELECT * FROM dbo.asset_class';
lADOCommand.CommandType := 1;
lADOCommand.CommandTimeout := 0;
lADOCommand.Execute;
//**************************************
IF ISCLEAR(lADORecordset) THEN
CREATE(lADORecordset);
lADORecordset.ActiveConnection := lvarActiveConnection;
lADORecordset.Open(lADOCommand);
WHILE NOT lADORecordset.EOF DO BEGIN
message('record from SQL');
lADORecordset.MoveNext;
//**********************************************
//CLOSE CONNECTION
lADOConnection.Close;
CLEAR(lADOConnection);
And here are my global variables:
lADOConnection@1000000000 : Automation "{2A75196C-D9EB-4129-B803-931327F72D5C} 2.8:{00000514-0000-0010-8000-00AA006D2EA4}:'Microsoft ActiveX Data Objects 2.8 Library'.Connection";
lADOCommand@1000000001 : Automation "{2A75196C-D9EB-4129-B803-931327F72D5C} 2.8:{00000507-0000-0010-8000-00AA006D2EA4}:'Microsoft ActiveX Data Objects 2.8 Library'.Command";
lADORecordSet@1000000003 : Automation "{2A75196C-D9EB-4129-B803-931327F72D5C} 2.8:{00000535-0000-0010-8000-00AA006D2EA4}:'Microsoft ActiveX Data Objects 2.8 Library'.Recordset";
lvarActiveConnection@1000000002 : Variant;
Can you tell me where the debugger errors out, and what the message is (again)?
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
I was thinking that I defined my lADORecordset variable wrong but don't know how else I would define it....
Can you check if there is a double name present (locals and globals perhaps?)?
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
=D>
Okay, now on to doing something with the recordset. I'll post again if I run into anything else
Thanks so much for your help!
Kelly
CODE:
*********************************
CLEAR(lADOCommand);
CREATE(lADOCommand);
lvarActiveConnection := lADOConnection;
lADOCommand.ActiveConnection := lvarActiveConnection;
//GET RECORD SET
lADOCommand.CommandText := 'SELECT * FROM asset_class WHERE class_name = ''' + FAClassRec.Code + '''';
lADOCommand.CommandType := 1;
lADOCommand.CommandTimeout := 0;
lADOCommand.Execute;
CLEAR(lADORecordSet);
CREATE(lADORecordSet);
lADORecordSet.ActiveConnection := lvarActiveConnection;
lADORecordSet.Open(lADOCommand);
EVALUATE(rcount,FORMAT(lADORecordSet.RecordCount));
IF rcount > 0 THEN
MESSAGE('record found')
ELSE
MESSAGE('record not found');
*********************************
END OF CODE
If I copy my select statement to the Query Analyzer it works fine too.
Anything
Kelly
So the -1 just wants to say that there are records, but not how many.
No PM,please use the forum. || May the <SOLVED>-attribute be in your title!
lADOCommand.CommandText := 'SELECT count(*) FROM asset_class WHERE class_name = ''' + FAClassRec.Code + '''';
in this case, you get only one record, one field. that fields gives you the number of records.
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
So if you don't REALLY need the number of records, better avoid this request.
No PM,please use the forum. || May the <SOLVED>-attribute be in your title!
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
In this case:
And then test lADORecordSet.RecordCount if it is '-1' or '0'.
No PM,please use the forum. || May the <SOLVED>-attribute be in your title!
Eric Wauters
MVP - Microsoft Dynamics NAV
My blog
Unfortunately, when I changed my select statement to
I get a run time error - Incorrect syntax near the keyword 'NULL'.
I copied in your select statement exact, was that what I was suppose to do?
Thanks so much for any help
Kelly