SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Converting between binary hex and GUID (uniqueidentifier)


Converting between binary hex and GUID (uniqueidentifier)

Author
Message
jay-h
jay-h
SSCoach
SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)

Group: General Forum Members
Points: 15939 Visits: 2805
Sounds easy. but I'm trying to connect the [step_uid] field in msdb.dbo.sysjob (uniqueidentifier) to the text based binary version in in master.dbo.sysprocesses [Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)')

I've been searching Google, but the examples posted seems to be people glibly suggesting using convert (or cast) as below. But this is simply NOT working. For example, if I try to convert the value (from above example) as suggested by a number of people:

print convert(uniqueidentifier, convert(binary(16), '0x6C7DC5120E8CA94F8224D0198C9D7CF2'))

Result: 43367830-4437-3543-3132-304538434139

The result of this approach is not correct. For one thing, it has no (hex) letters and does not match up to any jobs. In fact no conversions using this technique seem to every show letters--even though the values quoted in .sysjobs certainly do.

If I try to reverse the process which SHOULD get me tack to where I started
print convert(binary(16), '43367830-4437-3543-3132-304538434139')

I get this: 0x34333336373833302D343433372D3335, which is nonsensical.

Bottom line: does ANYONE have a reliable way to translate between binary and GUID (uniqueidentifier) formats?

...

-- FORTRAN manual for Xerox Computers --
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)

Group: General Forum Members
Points: 396632 Visits: 43199
jay-h - Thursday, November 8, 2018 12:49 PM
Sounds easy. but I'm trying to connect the [step_uid] field in msdb.dbo.sysjob (uniqueidentifier) to the text based binary version in in master.dbo.sysprocesses [Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)')

I've been searching Google, but the examples posted seems to be people glibly suggesting using convert (or cast) as below. But this is simply NOT working. For example, if I try to convert the value (from above example) as suggested by a number of people:

print convert(uniqueidentifier, convert(binary(16), '0x6C7DC5120E8CA94F8224D0198C9D7CF2'))

Result: 43367830-4437-3543-3132-304538434139

The result of this approach is not correct. For one thing, it has no (hex) letters and does not match up to any jobs. In fact no conversions using this technique seem to every show letters--even though the values quoted in .sysjobs certainly do.

If I try to reverse the process which SHOULD get me tack to where I started
print convert(binary(16), '43367830-4437-3543-3132-304538434139')

I get this: 0x34333336373833302D343433372D3335, which is nonsensical.

Bottom line: does ANYONE have a reliable way to translate between binary and GUID (uniqueidentifier) formats?

Well, there is this:

declare @TestUI uniqueidentifier = '43367830-4437-3543-3132-304538434139';

select @TestUI, '43367830-4437-3543-3132-304538434139';


Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Y.B.
Y.B.
SSCrazy Eights
SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)

Group: General Forum Members
Points: 9397 Visits: 2662
This seems to work fine for me unless I'm missing something...

DECLARE @guid UNIQUEIDENTIFIER, @binary VARBINARY(16)

SELECT @guid = NEWID()

SELECT @binary = CAST(@guid AS VARBINARY(16))

SELECT
@guid AS Here,
@binary AS There,
CAST(@binary AS UNIQUEIDENTIFIER) AS BackAgain



SELECT quote FROM brain WHERE original = 1
0 rows returned
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)

Group: General Forum Members
Points: 396632 Visits: 43199
Lynn Pettis - Thursday, November 8, 2018 1:02 PM
jay-h - Thursday, November 8, 2018 12:49 PM
Sounds easy. but I'm trying to connect the [step_uid] field in msdb.dbo.sysjob (uniqueidentifier) to the text based binary version in in master.dbo.sysprocesses [Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)')

I've been searching Google, but the examples posted seems to be people glibly suggesting using convert (or cast) as below. But this is simply NOT working. For example, if I try to convert the value (from above example) as suggested by a number of people:

print convert(uniqueidentifier, convert(binary(16), '0x6C7DC5120E8CA94F8224D0198C9D7CF2'))

Result: 43367830-4437-3543-3132-304538434139

The result of this approach is not correct. For one thing, it has no (hex) letters and does not match up to any jobs. In fact no conversions using this technique seem to every show letters--even though the values quoted in .sysjobs certainly do.

If I try to reverse the process which SHOULD get me tack to where I started
print convert(binary(16), '43367830-4437-3543-3132-304538434139')

I get this: 0x34333336373833302D343433372D3335, which is nonsensical.

Bottom line: does ANYONE have a reliable way to translate between binary and GUID (uniqueidentifier) formats?

Well, there is this:

declare @TestUI uniqueidentifier = '43367830-4437-3543-3132-304538434139';

select @TestUI, '43367830-4437-3543-3132-304538434139';

And after playing a little more:

declare @TestUI uniqueidentifier = '43367830-4437-3543-3132-304538434139'
,@TestBin binary(16) = 0x6C7DC5120E8CA94F8224D0198C9D7CF2;

select @TestUI, '43367830-4437-3543-3132-304538434139';

select cast(@TestUI as varbinary(16)), cast(cast(@TestUI as varbinary(16)) as uniqueidentifier);

select
@TestBin
, convert(varchar(36),@TestBin,2)
, stuff(stuff(stuff(stuff(convert(varchar(36),@TestBin,2),21,0,'-'),17,0,'-'),13,0,'-'),9,0,'-')
, cast(stuff(stuff(stuff(stuff(convert(varchar(36),@TestBin,2),21,0,'-'),17,0,'-'),13,0,'-'),9,0,'-') as uniqueidentifier)


Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)

Group: General Forum Members
Points: 884753 Visits: 47951
jay-h - Thursday, November 8, 2018 12:49 PM
Sounds easy. but I'm trying to connect the [step_uid] field in msdb.dbo.sysjob (uniqueidentifier) to the text based binary version in in master.dbo.sysprocesses [Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)')

I've been searching Google, but the examples posted seems to be people glibly suggesting using convert (or cast) as below. But this is simply NOT working. For example, if I try to convert the value (from above example) as suggested by a number of people:

print convert(uniqueidentifier, convert(binary(16), '0x6C7DC5120E8CA94F8224D0198C9D7CF2'))

Result: 43367830-4437-3543-3132-304538434139

The result of this approach is not correct. For one thing, it has no (hex) letters and does not match up to any jobs. In fact no conversions using this technique seem to every show letters--even though the values quoted in .sysjobs certainly do.

If I try to reverse the process which SHOULD get me tack to where I started
print convert(binary(16), '43367830-4437-3543-3132-304538434139')

I get this: 0x34333336373833302D343433372D3335, which is nonsensical.

Bottom line: does ANYONE have a reliable way to translate between binary and GUID (uniqueidentifier) formats?

This will do it for you. I also took the liberty of splitting the desired value out of the original message.

--===== This isn't part of the solution. We're just creating the message as a test.
DECLARE @Msg VARCHAR(1000) = '[Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)'')'
;
--===== This splits the "binary" (hex, really) from the message and then, using CONVERT with a "1" format,
-- converts the text to a BINARY(16) and then converts that to the final GUID.
SELECT CONVERT(UNIQUEIDENTIFIER,CONVERT(BINARY(16),SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34),1))
;


For more information on the convert format of "1" that I used, search for "Binary Style" in the article at the following link...
https://docs.microsoft.com/en-us/sql/t-sql/functions/cast-and-convert-transact-sql?view=sql-server-2017


--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)

Group: General Forum Members
Points: 396632 Visits: 43199
Jeff Moden - Thursday, November 8, 2018 10:05 PM
jay-h - Thursday, November 8, 2018 12:49 PM
Sounds easy. but I'm trying to connect the [step_uid] field in msdb.dbo.sysjob (uniqueidentifier) to the text based binary version in in master.dbo.sysprocesses [Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)')

I've been searching Google, but the examples posted seems to be people glibly suggesting using convert (or cast) as below. But this is simply NOT working. For example, if I try to convert the value (from above example) as suggested by a number of people:

print convert(uniqueidentifier, convert(binary(16), '0x6C7DC5120E8CA94F8224D0198C9D7CF2'))

Result: 43367830-4437-3543-3132-304538434139

The result of this approach is not correct. For one thing, it has no (hex) letters and does not match up to any jobs. In fact no conversions using this technique seem to every show letters--even though the values quoted in .sysjobs certainly do.

If I try to reverse the process which SHOULD get me tack to where I started
print convert(binary(16), '43367830-4437-3543-3132-304538434139')

I get this: 0x34333336373833302D343433372D3335, which is nonsensical.

Bottom line: does ANYONE have a reliable way to translate between binary and GUID (uniqueidentifier) formats?

This will do it for you. I also took the liberty of splitting the desired value out of the original message.

--===== This isn't part of the solution. We're just creating the message as a test.
DECLARE @Msg VARCHAR(1000) = '[Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)'')'
;
--===== This splits the "binary" (hex, really) from the message and then, using CONVERT with a "1" format,
-- converts the text to a BINARY(16) and then converts that to the final GUID.
SELECT CONVERT(UNIQUEIDENTIFIER,CONVERT(BINARY(16),SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34),1))
;


For more information on the convert format of "1" that I used, search for "Binary Style" in the article at the following link...
https://docs.microsoft.com/en-us/sql/t-sql/functions/cast-and-convert-transact-sql?view=sql-server-2017

Actually, Jeff, your code doesn't quite work. Look at the following:

--===== This isn't part of the solution. We're just creating the message as a test.
DECLARE @Msg VARCHAR(1000) = '[Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)'')'
;
--===== This splits the "binary" (hex, really) from the message and then, using CONVERT with a "1" format,
-- converts the text to a BINARY(16) and then converts that to the final GUID.
SELECT SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34), convert(UNIQUEIDENTIFIER,CONVERT(BINARY(16),SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34),1))
select SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34), cast(stuff(stuff(stuff(stuff(convert(varchar(36),convert(varbinary(16),substring(@Msg,CHARINDEX('Job 0x',@Msg)+4,34),1),2),21,0,'-'),17,0,'-'),13,0,'-'),9,0,'-') as uniqueidentifier);
;


Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
jay-h
jay-h
SSCoach
SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)

Group: General Forum Members
Points: 15939 Visits: 2805
Thanks for the input. Monday I hope to dig back into this.

...

-- FORTRAN manual for Xerox Computers --
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)SSC Guru (884K reputation)

Group: General Forum Members
Points: 884753 Visits: 47951
Lynn Pettis - Friday, November 9, 2018 8:44 AM
Jeff Moden - Thursday, November 8, 2018 10:05 PM
jay-h - Thursday, November 8, 2018 12:49 PM
Sounds easy. but I'm trying to connect the [step_uid] field in msdb.dbo.sysjob (uniqueidentifier) to the text based binary version in in master.dbo.sysprocesses [Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)')

I've been searching Google, but the examples posted seems to be people glibly suggesting using convert (or cast) as below. But this is simply NOT working. For example, if I try to convert the value (from above example) as suggested by a number of people:

print convert(uniqueidentifier, convert(binary(16), '0x6C7DC5120E8CA94F8224D0198C9D7CF2'))

Result: 43367830-4437-3543-3132-304538434139

The result of this approach is not correct. For one thing, it has no (hex) letters and does not match up to any jobs. In fact no conversions using this technique seem to every show letters--even though the values quoted in .sysjobs certainly do.

If I try to reverse the process which SHOULD get me tack to where I started
print convert(binary(16), '43367830-4437-3543-3132-304538434139')

I get this: 0x34333336373833302D343433372D3335, which is nonsensical.

Bottom line: does ANYONE have a reliable way to translate between binary and GUID (uniqueidentifier) formats?

This will do it for you. I also took the liberty of splitting the desired value out of the original message.

--===== This isn't part of the solution. We're just creating the message as a test.
DECLARE @Msg VARCHAR(1000) = '[Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)'')'
;
--===== This splits the "binary" (hex, really) from the message and then, using CONVERT with a "1" format,
-- converts the text to a BINARY(16) and then converts that to the final GUID.
SELECT CONVERT(UNIQUEIDENTIFIER,CONVERT(BINARY(16),SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34),1))
;


For more information on the convert format of "1" that I used, search for "Binary Style" in the article at the following link...
https://docs.microsoft.com/en-us/sql/t-sql/functions/cast-and-convert-transact-sql?view=sql-server-2017

Actually, Jeff, your code doesn't quite work. Look at the following:

--===== This isn't part of the solution. We're just creating the message as a test.
DECLARE @Msg VARCHAR(1000) = '[Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)'')'
;
--===== This splits the "binary" (hex, really) from the message and then, using CONVERT with a "1" format,
-- converts the text to a BINARY(16) and then converts that to the final GUID.
SELECT SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34), convert(UNIQUEIDENTIFIER,CONVERT(BINARY(16),SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34),1))
select SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34), cast(stuff(stuff(stuff(stuff(convert(varchar(36),convert(varbinary(16),substring(@Msg,CHARINDEX('Job 0x',@Msg)+4,34),1),2),21,0,'-'),17,0,'-'),13,0,'-'),9,0,'-') as uniqueidentifier);
;


Ah... be careful now, Lynn. You have to remember that the value of 0x6C7DC5120E8CA94F8224D0198C9D7CF2 is NOT a GUID. It's the binary (hex) representation for the GUID. The code I posted is correct.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)SSC Guru (396K reputation)

Group: General Forum Members
Points: 396632 Visits: 43199
Jeff Moden - Friday, November 9, 2018 8:13 PM
Lynn Pettis - Friday, November 9, 2018 8:44 AM
Jeff Moden - Thursday, November 8, 2018 10:05 PM
jay-h - Thursday, November 8, 2018 12:49 PM
Sounds easy. but I'm trying to connect the [step_uid] field in msdb.dbo.sysjob (uniqueidentifier) to the text based binary version in in master.dbo.sysprocesses [Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)')

I've been searching Google, but the examples posted seems to be people glibly suggesting using convert (or cast) as below. But this is simply NOT working. For example, if I try to convert the value (from above example) as suggested by a number of people:

print convert(uniqueidentifier, convert(binary(16), '0x6C7DC5120E8CA94F8224D0198C9D7CF2'))

Result: 43367830-4437-3543-3132-304538434139

The result of this approach is not correct. For one thing, it has no (hex) letters and does not match up to any jobs. In fact no conversions using this technique seem to every show letters--even though the values quoted in .sysjobs certainly do.

If I try to reverse the process which SHOULD get me tack to where I started
print convert(binary(16), '43367830-4437-3543-3132-304538434139')

I get this: 0x34333336373833302D343433372D3335, which is nonsensical.

Bottom line: does ANYONE have a reliable way to translate between binary and GUID (uniqueidentifier) formats?

This will do it for you. I also took the liberty of splitting the desired value out of the original message.

--===== This isn't part of the solution. We're just creating the message as a test.
DECLARE @Msg VARCHAR(1000) = '[Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)'')'
;
--===== This splits the "binary" (hex, really) from the message and then, using CONVERT with a "1" format,
-- converts the text to a BINARY(16) and then converts that to the final GUID.
SELECT CONVERT(UNIQUEIDENTIFIER,CONVERT(BINARY(16),SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34),1))
;


For more information on the convert format of "1" that I used, search for "Binary Style" in the article at the following link...
https://docs.microsoft.com/en-us/sql/t-sql/functions/cast-and-convert-transact-sql?view=sql-server-2017

Actually, Jeff, your code doesn't quite work. Look at the following:

--===== This isn't part of the solution. We're just creating the message as a test.
DECLARE @Msg VARCHAR(1000) = '[Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)'')'
;
--===== This splits the "binary" (hex, really) from the message and then, using CONVERT with a "1" format,
-- converts the text to a BINARY(16) and then converts that to the final GUID.
SELECT SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34), convert(UNIQUEIDENTIFIER,CONVERT(BINARY(16),SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34),1))
select SUBSTRING(@Msg,CHARINDEX('Job 0x',@Msg)+4,34), cast(stuff(stuff(stuff(stuff(convert(varchar(36),convert(varbinary(16),substring(@Msg,CHARINDEX('Job 0x',@Msg)+4,34),1),2),21,0,'-'),17,0,'-'),13,0,'-'),9,0,'-') as uniqueidentifier);
;


Ah... be careful now, Lynn. You have to remember that the value of 0x6C7DC5120E8CA94F8224D0198C9D7CF2 is NOT a GUID. It's the binary (hex) representation for the GUID. The code I posted is correct.


But if you compare that value to the value from the other table it matches. At least that is what I was seeing the OPs original post.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Eirikur Eiriksson
Eirikur Eiriksson
SSC Guru
SSC Guru (162K reputation)SSC Guru (162K reputation)SSC Guru (162K reputation)SSC Guru (162K reputation)SSC Guru (162K reputation)SSC Guru (162K reputation)SSC Guru (162K reputation)SSC Guru (162K reputation)

Group: General Forum Members
Points: 162158 Visits: 23651
jay-h - Thursday, November 8, 2018 12:49 PM
Sounds easy. but I'm trying to connect the [step_uid] field in msdb.dbo.sysjob (uniqueidentifier) to the text based binary version in in master.dbo.sysprocesses [Program_name] (example ''SQLAgent - TSQL JobStep (Job 0x6C7DC5120E8CA94F8224D0198C9D7CF2 : Step 1)')

I've been searching Google, but the examples posted seems to be people glibly suggesting using convert (or cast) as below. But this is simply NOT working. For example, if I try to convert the value (from above example) as suggested by a number of people:

print convert(uniqueidentifier, convert(binary(16), '0x6C7DC5120E8CA94F8224D0198C9D7CF2'))

Result: 43367830-4437-3543-3132-304538434139

The result of this approach is not correct. For one thing, it has no (hex) letters and does not match up to any jobs. In fact no conversions using this technique seem to every show letters--even though the values quoted in .sysjobs certainly do.

If I try to reverse the process which SHOULD get me tack to where I started
print convert(binary(16), '43367830-4437-3543-3132-304538434139')

I get this: 0x34333336373833302D343433372D3335, which is nonsensical.

Bottom line: does ANYONE have a reliable way to translate between binary and GUID (uniqueidentifier) formats?

The reason this is not working is that you are comparing a string and a binary that "look" the same.
Cool

0x6C7DC5120E8CA94F8224D0198C9D7CF2 is not the same as '0x6C7DC5120E8CA94F8224D0198C9D7CF2', you are using the latter when you should be using the former.

CONVERT(UNIQUEIDENTIFIER, 0x6C7DC5120E8CA94F8224D0198C9D7CF2,1);


To convert a string into binary, one has to use the convert function with the format parameter value of 1.


DECLARE @BINSTR VARCHAR(36) = '0x6C7DC5120E8CA94F8224D0198C9D7CF2';
SELECT
@BINSTR
,CONVERT(VARBINARY(16),@BINSTR,0) BAD_BIN
,CONVERT(VARBINARY(16),@BINSTR,1) OK_BIN
;

Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search