Programmaticallychange a field type to Hyperlink (1 Viewer)

kiloez

New member
Local time
Today, 05:03
Joined
Jan 7, 2008
Messages
7
Is there a way to use VBA or Access SQL to change a field type in a table to Hyperlink?

I can change a field type to text using the following SQL: ALTER TABLE TableName ALTER COLUMN ColumnName TEXT(255)... works like a charm.

However, the following SQL fails: ALTER TABLE TableName ALTER COLUMN ColumnName HYPERLINK

Taking a look at Type Conversion functions I don't see, can't find anything I can use with VBA. Is there's an API function available?

Any help would be greatly appreciated.
 

Ranman256

Well-known member
Local time
Today, 05:03
Joined
Apr 9, 2015
Messages
4,337
Paste this code into a module, and it will open ANY file in its native application.

usage: OpenNativeApp "c:\folder\file.pdf"
will open it in acrobat
and
OpenNativeApp ME.txtBox
will open the URL in the box using IE , if the item in txtBox is http:...

Code:
'Attribute VB_Name = "modNativeApp"
'Option Compare Database
Option Explicit

Private Declare Function ShellExecute Lib "shell32.dll" Alias "ShellExecuteA" (ByVal hwnd As Long, ByVal lpszOp As String, ByVal lpszFile As String, ByVal lpszParams As String, ByVal lpszDir As String, ByVal FsShowCmd As Long) As Long

Private Declare Function GetDesktopWindow Lib "user32" () As Long
Const SW_SHOWNORMAL = 1
Const SE_ERR_FNF = 2&
Const SE_ERR_PNF = 3&
Const SE_ERR_ACCESSDENIED = 5&
Const SE_ERR_OOM = 8&
Const SE_ERR_DLLNOTFOUND = 32&
Const SE_ERR_SHARE = 26&
Const SE_ERR_ASSOCINCOMPLETE = 27&
Const SE_ERR_DDETIMEOUT = 28&
Const SE_ERR_DDEFAIL = 29&
Const SE_ERR_DDEBUSY = 30&
Const SE_ERR_NOASSOC = 31&
Const ERROR_BAD_FORMAT = 11&


Public Sub OpenNativeApp(ByVal psDocName As String)
Dim r As Long, msg As String

r = StartDoc(psDocName)
If r <= 32 Then
    'There was an error
    Select Case r
        Case SE_ERR_FNF
            msg = "File not found"
        Case SE_ERR_PNF
            msg = "Path not found"
        Case SE_ERR_ACCESSDENIED
            msg = "Access denied"
        Case SE_ERR_OOM
            msg = "Out of memory"
        Case SE_ERR_DLLNOTFOUND
            msg = "DLL not found"
        Case SE_ERR_SHARE
            msg = "A sharing violation occurred"
        Case SE_ERR_ASSOCINCOMPLETE
            msg = "Incomplete or invalid file association"
        Case SE_ERR_DDETIMEOUT
            msg = "DDE Time out"
        Case SE_ERR_DDEFAIL
            msg = "DDE transaction failed"
        Case SE_ERR_DDEBUSY
            msg = "DDE busy"
        Case SE_ERR_NOASSOC
            msg = "No association for file extension"
        Case ERROR_BAD_FORMAT
            msg = "Invalid EXE file or error in EXE image"
        Case Else
            msg = "Unknown error"
    End Select
'    MsgBox msg
End If
End Sub
 

arnelgp

..forever waiting... waiting for jellybean!
Local time
Today, 17:03
Joined
May 7, 2009
Messages
19,245
there is no direct way to do this in dao, except adding a new hyperlink field, copying the content of the old field to hyperlink field, deleting the oldfield and renaming the hyperlink field to the name of old field.
Code:
Public Sub ChangeTextFieldToHyperLink(table As String, fieldname As String)

    Dim db As DAO.Database, tdf As DAO.TableDef, fld As DAO.Field, sSQL As String

   'Append a new Hyperlink column
   Set db = CurrentDb
   Set tdf = db.TableDefs(table)
   Set fld = tdf.CreateField("NewHyperlinkColumnName", dbMemo)
   fld.Attributes = dbHyperlinkField
   tdf.Fields.Append fld
   
   'Update the Hyperlink column from 'StringColumn'
   sSQL = "UPDATE " & table & " SET NewHyperlinkColumnName = " & fieldname & ";"
   DoCmd.SetWarnings False
   db.Execute (sSQL)
   DoCmd.SetWarnings True
   
   'Delete column 'StringColumn'
   tdf.Fields.Delete fieldname
   fld.Name = fieldname
   
   Set fld = Nothing
   Set tdf = Nothing
   Set db = Nothing
End Sub
 

Users who are viewing this thread

Top Bottom