Results 1 to 13 of 13
  1. #1
    clukem is offline Novice
    Windows 11 Access 2016
    Join Date
    Sep 2024
    Posts
    16

    Displaying a result set from a stored procedure with multiple entries

    I have a query (below), which lists the phones connected to particular desk.


    Private Sub DeskSearch_Click()
    Dim db As Database
    Dim cnn As ADODB.Connection
    Dim rs As ADODB.Recordset

    Set cnn = New ADODB.Connection
    Set rs = New ADODB.Recordset

    Set cnn = New ADODB.Connection

    cnn.ConnectionString = "Driver={SQL Server};Server=LAPTOP-A35N8041;Database=PhoneDB;Trusted_Connection=yes"

    cnn.Open

    Set rs = New ADODB.Recordset
    Set rs = cnn.Execute("Exec dbo.DeskSearch '" & [Location] & "'")




    Prior to moving the tables to an SQL server, I could do an SQL query to return the data. I have a stored procedure on the server called DeskSearch



    When the result is run the output is like





    I've got the code as far as being executed, but not sure how to display it similar to above. Has anyone any ideas



    Regards


    Chris

  2. #2
    Join Date
    Jun 2010
    Location
    Belgium
    Posts
    1,180
    Have you already tried to use an ADODB.command object for this?

  3. #3
    pbaldy's Avatar
    pbaldy is offline Who is John Galt?
    Windows XP Access 2007
    Join Date
    Feb 2010
    Location
    Nevada, USA
    Posts
    22,652
    You could use a pass through query and make it the source of a form/report for viewing. I feel like I've heard you can set a report's source to your recordset, but not sure off the top of my head.
    Paul (wino moderator)
    MS Access MVP 2007-2019
    www.BaldyWeb.com

  4. #4
    Join Date
    Jan 2017
    Location
    Swansea,South Wales,UK
    Posts
    6,556
    Like what?
    I do not see anything?

    You cannot paste pictures on this site, but need to attach them.
    Please use # icon on toolbar when posting code snippets.
    Cross Posting: https://www.excelguru.ca/content.php?184
    Debugging Access: https://www.youtube.com/results?sear...bug+access+vba

  5. #5
    CJ_London is offline VIP
    Windows 10 Access 2010 32bit
    Join Date
    Mar 2015
    Posts
    11,933
    I feel like I've heard you can set a report's source to your recordset
    You can't with an ado recordset, only a dao recordset

  6. #6
    pbaldy's Avatar
    pbaldy is offline Who is John Galt?
    Windows XP Access 2007
    Join Date
    Feb 2010
    Location
    Nevada, USA
    Posts
    22,652
    Quote Originally Posted by CJ_London View Post
    You can't with an ado recordset, only a dao recordset
    Ah, thanks for the clarification. I'd use a pass through query, so haven't tried this.
    Paul (wino moderator)
    MS Access MVP 2007-2019
    www.BaldyWeb.com

  7. #7
    CJ_London is offline VIP
    Windows 10 Access 2010 32bit
    Join Date
    Mar 2015
    Posts
    11,933
    To clarify that was referring to ADO and reports. You can use ADO to populate forms (which can be datasheet forms), combo's or listboxes. But be aware that with forms, sorting and filtering using the access built in functionality will fail - you need to build your own.

    Not tried using a passthrough query for reports

  8. #8
    clukem is offline Novice
    Windows 11 Access 2016
    Join Date
    Sep 2024
    Posts
    16
    Click image for larger version. 

Name:	query.jpg 
Views:	16 
Size:	70.9 KB 
ID:	52309Click image for larger version. 

Name:	Procedure.jpg 
Views:	16 
Size:	40.1 KB 
ID:	52310

    Attachments added of code and output. I've seen a comment that an access pass through query cannot take parameters

  9. #9
    clukem is offline Novice
    Windows 11 Access 2016
    Join Date
    Sep 2024
    Posts
    16
    This is the response when using pass through
    Click image for larger version. 

Name:	PassThrough.jpg 
Views:	18 
Size:	38.3 KB 
ID:	52311

  10. #10
    Minty is offline VIP
    Windows 10 Office 365
    Join Date
    Sep 2017
    Location
    UK - Wiltshire
    Posts
    3,157
    You Can't pass the form reference to SQL server it has no clue what it is.
    You need to pass the actual value into the pass through .

    Code:
        Dim db As DAO.Database
        Dim qDef As QueryDef
        Dim StrSQl as string
    
        StrSQL = "SELECT YourFields FROM Phones WHERE Location = '" & Forms!DeskSearch!Location & "'"
    
    
        Set db = CurrentDb()
        
        Set qDef = db.QueryDefs("Your_Saved_PT_Query")
        qDef.Connect = db.TableDefs("A_SQL_LinkedTable").Connect
        qDef.SQL = StrSQL 
        qDef.ReturnsRecords = True
        qDef.Close 
    
    
        Set qDef = Nothing
        Set db = Nothing
    You can now use Your_Saved_PT_Query as the recordsource.

    However, unless your table has millions of rows, simply link to it and create a local query to do the filtering.
    This isn't a efficient use of a pass through, it's only one table filtered.
    DLookup Syntax and others http://access.mvps.org/access/general/gen0018.htm
    Please use the star below the post to say thanks if we have helped !
    ↓↓ It's down here ↓↓

  11. #11
    pbaldy's Avatar
    pbaldy is offline Who is John Galt?
    Windows XP Access 2007
    Join Date
    Feb 2010
    Location
    Nevada, USA
    Posts
    22,652
    Minty has already addressed your error, but I should have clarified that I'd have started with linked tables and an Access query too. My rule of thumb is to use Access queries until performance dictates otherwise.
    Paul (wino moderator)
    MS Access MVP 2007-2019
    www.BaldyWeb.com

  12. #12
    clukem is offline Novice
    Windows 11 Access 2016
    Join Date
    Sep 2024
    Posts
    16
    Quote Originally Posted by Minty View Post
    You Can't pass the form reference to SQL server it has no clue what it is.
    You need to pass the actual value into the pass through .

    Code:
        Dim db As DAO.Database
        Dim qDef As QueryDef
        Dim StrSQl as string
    
        StrSQL = "SELECT YourFields FROM Phones WHERE Location = '" & Forms!DeskSearch!Location & "'"
    
    
        Set db = CurrentDb()
        
        Set qDef = db.QueryDefs("Your_Saved_PT_Query")
        qDef.Connect = db.TableDefs("A_SQL_LinkedTable").Connect
        qDef.SQL = StrSQL 
        qDef.ReturnsRecords = True
        qDef.Close 
    
    
        Set qDef = Nothing
        Set db = Nothing
    You can now use Your_Saved_PT_Query as the recordsource.

    However, unless your table has millions of rows, simply link to it and create a local query to do the filtering.
    This isn't a efficient use of a pass through, it's only one table filtered.

    I originally had just an access database with all the data in there. Then I was asked to keep the data on a SQL server. So, linked the tables using migration assistant. I was just trying to get as much as possible in stored procedures on the SQL server. Where people can't easily reach. Wil have to take a look at QDEF at some point

  13. #13
    pbaldy's Avatar
    pbaldy is offline Who is John Galt?
    Windows XP Access 2007
    Join Date
    Feb 2010
    Location
    Nevada, USA
    Posts
    22,652
    I use a function that "fixes" the SQL of pass through queries so I only need the QueryDef code in one place. I got it from a book but I think this is the same code:

    From Access to SQL Server – SQLServerCentral Forums


    The PassThroughFixup function about half way down. On SQL Server I started using table-valued functions as much as stored procedures, since they can be used in a FROM clause.
    Paul (wino moderator)
    MS Access MVP 2007-2019
    www.BaldyWeb.com

Please reply to this thread with any new information or opinions.

Similar Threads

  1. Replies: 33
    Last Post: 09-25-2015, 08:39 AM
  2. Replies: 1
    Last Post: 04-13-2010, 12:18 PM
  3. Replies: 1
    Last Post: 11-17-2009, 06:55 AM
  4. Replies: 0
    Last Post: 10-04-2009, 04:11 AM
  5. stored procedure return value to access form
    By rbw940 in forum Programming
    Replies: 0
    Last Post: 10-13-2008, 01:31 PM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  
Other Forums: Microsoft Office Forums