├── README.md ├── LICENSE └── jwt.sql /README.md: -------------------------------------------------------------------------------- 1 | # tsql-jwt 2 | JSON Web Tokens in T-SQL for SQL Server 3 | 4 | # Example Usage 5 | ```sql 6 | select dbo.JWT_Encode(dbo.XmlToJson((select 'HS256' alg, 'JWT' typ for xml path, root)), 7 | dbo.XmlToJson((select 'chris' name, 'true' admin for xml path, root)), 8 | 'secret') 9 | ``` 10 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) 2015 Chris Blatchley 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | 23 | -------------------------------------------------------------------------------- /jwt.sql: -------------------------------------------------------------------------------- 1 | ---------------------------- 2 | -- XML to JSON Conversion -- 3 | ---------------------------- 4 | if object_id('dbo.XmlToJson') is not null 5 | drop function dbo.XmlToJson 6 | go 7 | 8 | create function dbo.XmlToJson(@xmldata xml) 9 | returns nvarchar(max) 10 | as 11 | begin 12 | 13 | declare @json nvarchar(max) 14 | 15 | select @json = concat(@json, ',{' 16 | + stuff( 17 | ( 18 | select ',"' 19 | + coalesce(b.c.value('local-name(.)', 'nvarchar(max)'), '') 20 | + '":"' 21 | + b.c.value('text()[1]','nvarchar(max)') 22 | + '"' 23 | 24 | from x.a.nodes('*') b(c) 25 | 26 | for xml path(''), type 27 | ).value('(./text())[1]', 'nvarchar(max)') 28 | 29 | , 1, 1, '' 30 | ) 31 | + '}') 32 | 33 | from @xmldata.nodes('/root/*') x(a) 34 | 35 | -- Remove leading comma 36 | return stuff(@json, 1, 1, '') 37 | 38 | end 39 | 40 | go 41 | 42 | grant execute on dbo.XmlToJson to public 43 | 44 | go 45 | 46 | --------------------- 47 | -- HMAC Encryption -- 48 | --------------------- 49 | /* 50 | Copyright © 2012 Ryan Malayter. All Rights Reserved. 51 | 52 | Redistribution and use in source and binary forms, with or without 53 | modification, are permitted provided that the following conditions are 54 | met: 55 | 56 | 1. Redistributions of source code must retain the above copyright 57 | notice, this list of conditions and the following disclaimer. 58 | 59 | 2. Redistributions in binary form must reproduce the above copyright 60 | notice, this list of conditions and the following disclaimer in the 61 | documentation and/or other materials provided with the distribution. 62 | 63 | 3. The name of the author may not be used to endorse or promote products 64 | derived from this software without specific prior written permission. 65 | 66 | THIS SOFTWARE IS PROVIDED BY Ryan Malayter "AS IS" AND ANY EXPRESS OR 67 | IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED 68 | WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 69 | DISCLAIMED. IN NO EVENT SHALL THE AUTHOR BE LIABLE FOR ANY DIRECT, 70 | INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES 71 | (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 72 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) 73 | HOWEVER CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, 74 | STRICT LIABILITY, OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN 75 | ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN IF ADVISED OF THE 76 | POSSIBILITY OF SUCH DAMAGE. 77 | */ 78 | 79 | /* 80 | This function only takes VARBINARY parameters instead of VARCHAR 81 | to prevent problems with implicit conversion from NVARCHAR to VARCHAR 82 | which result in incorrect hashes for inputs including non-ASCII characters. 83 | Always cast @key and @data parameters to VARBINARY when using this function. 84 | Tested against HMAC vectors for MD5 and SHA1 from RFC 2202 85 | */ 86 | 87 | /* 88 | List of secure hash algorithms (parameter @algo) supported by MSSQL 89 | version. This is what is passed to the HASHBYTES system function. 90 | Omit insecure hash algorithms such as MD2 through MD5 91 | 2005-2008R2: SHA1 92 | 2012-2016: SHA1 | SHA2_256 | SHA2_512 93 | */ 94 | create or alter function dbo.hmac ( 95 | @key varbinary(max), 96 | @data varbinary(MAX), 97 | @algo varchar(20) 98 | ) 99 | returns varbinary(64) 100 | as 101 | begin 102 | declare @ipad bigint 103 | declare @opad bigint 104 | declare @i varbinary(64) 105 | declare @o varbinary(64) 106 | declare @pos integer 107 | 108 | -- SQL 2005 only allows XOR operations on integer types, so use bigint and iterate 8 times 109 | set @ipad = cast(0x3636363636363636 as bigint) -- constants from HMAC definition 110 | set @opad = cast(0x5C5C5C5C5C5C5C5C as bigint) 111 | 112 | if len(@key) > 64 -- if the key is greater than 512 bits we hash it first per HMAC definition 113 | set @key = cast(hashbytes(@algo, @key) as binary (64)) 114 | else 115 | set @key = cast(@key as binary (64)) -- otherwise pad it out to 512 bits with zeros 116 | 117 | set @pos = 1 118 | set @i = cast('' AS varbinary(64)) -- initialize as empty binary value 119 | 120 | while @pos <= 57 121 | begin 122 | set @i = @i + cast((substring(@key, @pos, 8) ^ @ipad) as varbinary(64)) 123 | set @pos = @pos + 8 124 | end 125 | 126 | set @pos = 1 127 | set @o = cast('' as varbinary(64)) -- initialize as empty binary value 128 | 129 | while @pos <= 57 130 | begin 131 | set @o = @o + cast((substring(@key, @pos, 8) ^ @opad) as varbinary(64)) 132 | set @pos = @pos + 8 133 | end 134 | 135 | return hashbytes(@algo, @o + hashbytes(@algo, @i + @data)) 136 | end 137 | go 138 | 139 | grant execute on dbo.HMAC to public 140 | go 141 | 142 | --------------------- 143 | -- Base64 Encoding -- 144 | --------------------- 145 | if object_id('dbo.Base64') is not null 146 | drop function dbo.Base64 147 | go 148 | 149 | create function dbo.Base64( 150 | @data varbinary(max), 151 | @url_safe bit 152 | ) 153 | returns varchar(max) 154 | as 155 | begin 156 | declare @base64string varchar(max) 157 | 158 | -- When converting a table to json, binary data in the table is converted to a BASE64 String 159 | select @base64string = col 160 | from openjson( 161 | ( 162 | select col 163 | from (select @data col) T 164 | for json auto 165 | ) 166 | ) with(col varchar(max)) 167 | 168 | if @url_safe = 1 169 | begin 170 | select @base64string = replace(@base64string, '+', '-') 171 | select @base64string = replace(@base64string, '/', '_') 172 | end 173 | 174 | return @base64string 175 | end 176 | go 177 | 178 | grant execute on dbo.Base64 to public 179 | go 180 | 181 | ----------------------------- 182 | -- JSON Web Token Creation -- 183 | ----------------------------- 184 | create or alter function dbo.JWT_Encode( 185 | @json_header varchar(max), 186 | @json_payload varchar(max), 187 | @secret varchar(max) 188 | ) 189 | returns varchar(max) 190 | as 191 | begin 192 | 193 | declare @header varchar(max), 194 | @data varchar(max), 195 | @signature varchar(max); 196 | 197 | -- Base64 encode json header 198 | select @header = dbo.Base64(convert(varbinary(max), @json_header), 1); 199 | 200 | -- Base64 encode json payload 201 | select @data = dbo.Base64(convert(varbinary(max), @json_payload), 1); 202 | 203 | -- Generate signature 204 | select @signature = dbo.HMAC(convert(varbinary(max), @secret), convert(varbinary(max), @header + '.' + @data), 'SHA2_256'); 205 | 206 | -- Base64 encode signature 207 | select @signature = dbo.Base64(convert(varbinary(max), @signature), 1); 208 | 209 | return @header + '.' + @data + '.' + @signature; 210 | end 211 | go 212 | 213 | grant execute on dbo.JWT_Encode to public 214 | go 215 | 216 | ------------------- 217 | -- Example Usage -- 218 | ------------------- 219 | select dbo.JWT_Encode( 220 | dbo.XmlToJson((select 'HS256' alg, 'JWT' typ for xml path, root)), 221 | dbo.XmlToJson((select 'chris' name, 'true' admin for xml path, root)), 222 | 'secret' 223 | ) 224 | 225 | select dbo.JWT_Encode( 226 | (select 'HS256' alg, 'JWT' typ for json path, without_array_wrapper), 227 | (select 'brian' name, 'true' admin for json path, without_array_wrapper), 228 | 'secret' 229 | ) 230 | 231 | select dbo.JWT_Encode( 232 | '{"alg":"HS256","typ":"JWT"}', 233 | '{"name":"brian","admin":"true"}', 234 | 'secret' 235 | ) 236 | --------------------------------------------------------------------------------