Newbie Help Please

jerry
NewLounger
Posts: 12
Joined: 29 Jul 2010, 06:16

Newbie Help Please

Post by jerry »

Good Morning / Afternoon All

I was wondering if I could some help on this

I have an excel spreadsheet that lists various drawings on a column called SIGN DESIGN NUMBER. The cell contents on the picture 'E10' is based on the file name of the drawing in .PDF
In the nearby cell 'E9' I would like to create a hyperlink for the file
to do this I use a macro in another instance of excel and extract all the pdfs from a common directory and then cut the found hyperlinks and pasting the cells into 'E9'

is it possible to create a macro that says based on the contents of of one cell find the pdf and create a hyperlink

i tried to use lookup that would reference the second spreadsheet but it went all a little wonky when things werent in the right order

Overall I want to be able to create a macro that will extract all the information I need rather than cut and past please help

I hope the link works

http://picasaweb.google.com/10544579...eat=directlink" onclick="window.open(this.href);return false;

but here is the code is used to list all the pdf's in my directory

Code: Select all

Code:
 
Option Explicit
 
Sub SrchForFiles()
     ' Searches the selected folders and sub folders for files with the specified
     'extension.  .xls, .doc, .ppt, etc.
     'A new worksheet is produced called "File Search Results".  You can click on the link and go directly
     'to the file you need.
    Dim i As Long, z As Long, Rw As Long
    Dim ws As Worksheet
    Dim y As Variant
    Dim fLdr As String, Fil As String, FPath As String
 
    y = Application.InputBox("Please Enter File Extension", "Info Request")
    If y = False And Not TypeName(y) = "String" Then Exit Sub
    Application.ScreenUpdating = False
     '**********************************************************************
     'fLdr = BrowseForFolderShell
    With Application.FileDialog(msoFileDialogFolderPicker)
        .Show
        fLdr = .SelectedItems(1)
    End With
     '**********************************************************************
    With Application.FileSearch
        .NewSearch
        .LookIn = fLdr
        .SearchSubFolders = True
        .Filename = y
        Set ws = ThisWorkbook.Worksheets.Add(Sheets(1))
        On Error GoTo 1
2:                      ws.Name = "FileSearch Results"
        On Error GoTo 0
        If .Execute() > 0 Then
            For i = 1 To .FoundFiles.Count
                Fil = .FoundFiles(i)
                 'Get file path from file name
                FPath = Left(Fil, Len(Fil) - Len(Split(Fil, "\")(UBound(Split(Fil, "\")))) - 1)
                If Left$(Fil, 1) = Left$(fLdr, 1) Then
                    If CBool(Len(Dir(Fil))) Then
                        z = z + 1
                        ws.Cells(z + 1, 1).Resize(, 4) = _
                        Array(Dir(Fil), _
                        FileLen(Fil) / 1000, _
                        FileDateTime(Fil), _
                        FPath)
                        ws.Hyperlinks.Add Anchor:=Cells(z + 1, 1), _
                        Address:=.FoundFiles(i)
                    End If
                End If
            Next i
        End If
    End With
 
    ActiveWindow.DisplayHeadings = False
 
    With ws
        Rw = .Cells.Rows.Count
        With .[A1:D1]
            .Value = [{"Full Name","Kilobytes","Last Modified", "Path"}]
            .Font.Underline = xlUnderlineStyleSingle
            .EntireColumn.AutoFit
            .HorizontalAlignment = xlCenter
        End With
        .[E1:IV1 ].EntireColumn.Hidden = True
        On Error Resume Next
        Range(Cells(Rw, "A").End(3)(2), Cells(Rw, "A")).EntireRow.Hidden = True
        Range(.[A2 ], Cells(Rw, "C")).Sort [A2 ], xlAscending, Header:=xlNo
    End With
 
    Application.ScreenUpdating = True
    Exit Sub
1:          Application.DisplayAlerts = False
    Worksheets("FileSearch Results").Delete
    Application.DisplayAlerts = True
    GoTo 2
End Sub
I then sit down and go about extracting by cutting and pasting

arrrrrgh there must be something easier

User avatar
HansV
Administrator
Posts: 78616
Joined: 16 Jan 2010, 00:14
Status: Microsoft MVP
Location: Wageningen, The Netherlands

Re: Newbie Help Please

Post by HansV »

Welcome to Eileen's Lounge!

If you simply want a hyperlink to a single file, you can use a formula. Let's say that the .pdfs are in the folder C:\Common\Drawings.
With the filename in E8, the formula in E9 would become

=HYPERLINK("C:\Common\Drawings\"&E8)
Best wishes,
Hans

jerry
NewLounger
Posts: 12
Joined: 29 Jul 2010, 06:16

Re: Newbie Help Please

Post by jerry »

Good Evening Hans
New Picture (1).jpg
Thank you forthe quick reply

while this is good however the problem i have is that some of my staff are not super proffecient in actuality they ended up dragging to new columns and it was creating frustration
so to help them out i thought i would be able to create a button that would automate this as sometimes the drawings can be in the hundreds and might require redraws so thats where the code to extract the new pdfs come in


i have tried using the data sort functions but im coming aprt at the seams trying to figure out how this will work


i know im asking a terribly hard way to do a simple task but is there something you might be able to help me out with pretty please ???

some sort of macro would help
You do not have the required permissions to view the files attached to this post.

User avatar
HansV
Administrator
Posts: 78616
Joined: 16 Jan 2010, 00:14
Status: Microsoft MVP
Location: Wageningen, The Netherlands

Re: Newbie Help Please

Post by HansV »

I don't understand exactly what you're trying to do, and the screenshot is too small to read. Could you try to explain more clearly, and/or provide a readable screenshot?
Best wishes,
Hans

jerry
NewLounger
Posts: 12
Joined: 29 Jul 2010, 06:16

Re: Newbie Help Please

Post by jerry »

Sure Can

Okay heres the story

The design office have a series of plans for a site

the plans are divided into separate groups

now when a designer has finshed a set of plans the idea is to place a hyperlink to the pdf of this design so it is visble to other staff in other locations and by other people such as the works supervisor and so on

what used to happen was a designer would extract a hyperlink using the one suggested by yourself however it was not always linking to the correct file and and it would drop links

so a macro was created to extract all hyperlinks to the pdfs in one network directory

however this is a painfully slow process because you end up spending a day cutting and pasting all the tables with the chance of not cutting the right cells and messing up the spreadsheet

the macro finds all the pdfs no problem and extracts them into a new worksheet which is fine

now what im trying to do is based on the contents of the newly extracted hyperlinks to the pdf's which arent in the same order and don't all relate to the same project

i want to be able to extract what is in a Data Set 1 column A and match to the Sign Design .PDF Column in Data Set 2 worksheet

ill attach a bigger picture lets see how this goes

overall i want to thank you for taking the time to answer this and provide me with any feedback

Regards
Jerimia
DATA SET 1.JPG
You do not have the required permissions to view the files attached to this post.

User avatar
HansV
Administrator
Posts: 78616
Joined: 16 Jan 2010, 00:14
Status: Microsoft MVP
Location: Wageningen, The Netherlands

Re: Newbie Help Please

Post by HansV »

So, for example, cell E10 in the Data Set 2 sheet contains NEW_JEN_RD1. You want the macro to search for NEW_JEN_RD1.pdf in column A of the Data Set 1 sheet, and if found, copy the hyperlink to cell D10.

Is that correct?
Best wishes,
Hans

jerry
NewLounger
Posts: 12
Joined: 29 Jul 2010, 06:16

Re: Newbie Help Please

Post by jerry »

Correct

Is it possible to automate this

User avatar
HansV
Administrator
Posts: 78616
Joined: 16 Jan 2010, 00:14
Status: Microsoft MVP
Location: Wageningen, The Netherlands

Re: Newbie Help Please

Post by HansV »

The following macro will populate column D in one go:

Code: Select all

Sub CreateHyperlinks()
  Dim wsh1 As Worksheet
  Dim wsh2 As Worksheet
  Dim r As Long
  Dim m As Long
  Dim rngFound As Range

  Application.ScreenUpdating = False

  Set wsh1 = Worksheets("Data Set 1")
  Set wsh2 = Worksheets("Data Set 2")
  m = wsh2.Range("E" & wsh2.Rows.Count).End(xlUp).Row
  For r = 10 To m
    If wsh2.Range("E" & r) = "" Then
      wsh2.Range("D" & r).ClearContents
    Else
      Set rngFound = wsh1.Range("A:A").Find _
        (What:=wsh2.Range("E" & r) & ".pdf", LookIn:=xlValues, _
        LookAt:=xlPart, MatchCase:=False)
      If rngFound Is Nothing Then
        wsh2.Range("D" & r).ClearContents
      Else
        rngFound.Copy Destination:=wsh2.Range("D" & r)
      End If
    End If
  Next r

  Application.ScreenUpdating = True
End Sub
It would also be possible to have the cell in column D update automatically if the user enters or edits a value in column E. Let me know if you need that.
Best wishes,
Hans

jerry
NewLounger
Posts: 12
Joined: 29 Jul 2010, 06:16

Re: Newbie Help Please

Post by jerry »

just tried it and it works a treat

the option to update would be much appreciated

thanks heaps



HANS IS THE MAN





this has helped me so much

again thanks soooooooo much

User avatar
HansV
Administrator
Posts: 78616
Joined: 16 Jan 2010, 00:14
Status: Microsoft MVP
Location: Wageningen, The Netherlands

Re: Newbie Help Please

Post by HansV »

For the automatic update option, right-click the sheet tab of Data Set 2.
Select View Code from the popup menu.
This will open the worksheet module in the Visual Basic Editor.
Copy the following code into it:

Code: Select all

Private Sub Worksheet_Change(ByVal Target As Range)
  Dim wsh1 As Worksheet
  Dim rngCell As Range
  Dim rngFound As Range

  If Not Intersect(Range("E10:E" & Rows.Count), Target) Is Nothing Then
    Application.ScreenUpdating = False
    Set wsh1 = Worksheets("Data Set 1")
    For Each rngCell In Intersect(Range("E10:E" & Rows.Count), Target)
      If rngCell = "" Then
        rngCell.Offset(0, -1).ClearContents
      Else
        Set rngFound = wsh1.Range("A:A").Find _
          (What:=rngCell.Value & ".pdf", LookIn:=xlValues, _
          LookAt:=xlPart, MatchCase:=False)
        If rngFound Is Nothing Then
          rngCell.Offset(0, -1).ClearContents
        Else
          rngFound.Copy Destination:=rngCell.Offset(0, -1)
        End If
      End If
    Next rngCell
    Application.ScreenUpdating = True
  End If
End Sub
Best wishes,
Hans

jerry
NewLounger
Posts: 12
Joined: 29 Jul 2010, 06:16

Re: Newbie Help Please

Post by jerry »

Hans
a very big thak you for everything you are shining beacon in the world of excel coders

If you are ever in sydney and you need a beer or a whole bunch beers or a meal for a week or the entire time you are here

you let me know bro you have made my night

Thanks so much anything i can do you let me know

regards


Regards

User avatar
HansV
Administrator
Posts: 78616
Joined: 16 Jan 2010, 00:14
Status: Microsoft MVP
Location: Wageningen, The Netherlands

Re: Newbie Help Please

Post by HansV »

Thanks for your kind words, I'm glad to have been able to help.

My colleague Claude will no doubt be willing to have a beer on behalf of me... :grin:
Best wishes,
Hans