Spreadsheet - Fetch
Retrieve a Google spreadsheet using SQL Server
- See SQLHTTP easy setup for Google Sheets
- See API Call documentation for parameter values and other information
- Create the stored procedure documented below
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 |
CREATE PROCEDURE usp_Google_SpreadSheet_Fetch( @Profile nvarchar(100), @spreadsheetId varchar(MAX), @ranges varchar(MAX) = NULL, @includeGridData bit = NULL, @Response nvarchar(MAX) OUTPUT, @StatusCode int OUTPUT, @StatusDescription nvarchar(MAX) OUTPUT) AS DECLARE @Text_includeGridData varchar(5) SET @Text_includeGridData = CASE WHEN @includeGridData = 0 THEN 'false' ELSE 'true' END DECLARE @URL nvarchar(MAX) DECLARE @QueryString nvarchar(MAX) DECLARE @HTTPSessionID uniqueidentifier SET @URL = 'https://sheets.googleapis.com/v4' EXEC SQLHTTP.net.UrlBuilder @URL OUTPUT, @Profile, 'spreadsheets', @spreadsheetId EXEC SQLHTTP.net.QueryStringBuilder @QueryString OUTPUT, @Profile, 'includeGridData', @Text_includeGridData, 'ranges', @ranges SET @URL = @URL + @QueryString EXEC SQLHTTP.net.HTTPSession @HTTPSessionID OUTPUT EXEC usp_Google_Auth_Header @Profile, @HTTPSessionID EXEC SQLHTTP.net.HTTPRequest @HTTPSessionID, @URL = @URL, @Method = 'GET', @ContentType = 'application/json', @StatusCode = @StatusCode OUTPUT, @StatusDescription = @StatusDescription OUTPUT, @Response = @Response OUTPUT GO |
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 |
DECLARE @Response nvarchar(MAX) DECLARE @StatusCode int DECLARE @StatusDescription nvarchar(MAX) DECLARE @Profile nvarchar(100) SET @Profile = 'My google' --Google API Bearer Token expires after an hour EXEC usp_Google_Auth_Refresh @Profile EXEC usp_Google_SpreadSheet_Fetch @Profile = @Profile, @spreadsheetId = '1i_MSZy6Q5eh2IgxT8tS1cWWLsktjcQZsUkNU4cxPAtk', @includeGridData = 1, @Response = @Response OUTPUT, @StatusCode = @StatusCode OUTPUT, @StatusDescription = @StatusDescription OUTPUT IF @StatusCode >= 400 EXEC SQLHTTP.net.RaiseHttpError @StatusCode, @StatusDescription, @Response ELSE BEGIN DECLARE @X xml SET @X = SQLHTTP.net.Json_To_Xml(@Response, '0') --The XPath syntax below was easily generated by executing the following commands: --EXEC SQLHTTP.net.XQueryHelper @X --and then executing: --EXEC SQLHTTP.net.XQueryHelper @X, 'JsonObject' -- SELECT T.C.value(N'@spreadsheetId', N'nvarchar(MAX)') AS [spreadsheetId] ,T.C.value(N'properties[1]/@title', N'nvarchar(MAX)') AS [title] ,T.C.value(N'properties[1]/@timeZone', N'nvarchar(MAX)') AS [timeZone] ,T.C.value(N'sheets[1]/JsonObject[1]/properties[1]/@sheetId', N'nvarchar(MAX)') AS [sheetId] ,T.C.value(N'sheets[1]/JsonObject[1]/properties[1]/@title', N'nvarchar(MAX)') AS [sheetTitle] ,T.C.value(N'sheets[1]/JsonObject[1]/properties[1]/@sheetType', N'nvarchar(MAX)') AS [sheetType] ,T.C.value(N'@spreadsheetUrl', N'nvarchar(MAX)') AS [spreadsheetUrl] FROM @X.nodes(N'/JsonObject') T(C) END |
1 2 3 4 5 |
spreadsheetId title timeZone sheetId sheetTitle sheetType spreadsheetUrl ------------------- ------------------ -------------------- ----------- ---------- ---------- ---------------------------------------- 1i_MSZy6Q5eh2Ig... Project Plan.xlsx America/Los_Angeles 1627549697 Sheet1 GRID https://docs.google.com/spreadsheets/... |
IMPORTANT DISCLAIMER
CODE/SQL ON THESE PAGES ARE PROVIDED AS-IS AND ARE AVAILABLE FOR ILLUSTRATIVE PURPOSES ONLY.
USERS ARE REQUIRED TO ABIDE BY THE TERMS AND CONDITIONS FOR USING REFERENCED THIRD PARTY WEBSITES AND/OR APIs FROM THEIR RESPECTIVE WEBSITES. WE DO NOT CONDONE ANY VIOLATION OF THIRD PARTY WEBSITES AND/OR APIs TERMS AND CONDITIONS USING OUR SOFTWARE.
USERS SHALL BE SOLELY RESPONSIBLE AND BE SOLELY LIABLE FOR VIOLATION OF ANY RULES SPECIFIED BY THIRD PARTIES FOR USING THEIR WEBSITES AND/OR APIs, OR INFRINGEMENT OF RIGHTS OF SUCH THIRD PARTIES.