CREATE DATABASE DB_SENDMAIL;
GO
USE DB_SENDMAIL;
GO
CREATE TABLE [dbo].[T_DESTINATAIRE_DST] (
[DST_ID] [int] IDENTITY (1, 1) NOT NULL ,
[DST_CODE] [char] (3) COLLATE French_CI_AS NOT NULL ,
[DST_NOM] [char] (32) COLLATE French_CI_AS NOT NULL ,
[DST_PRENOM] [varchar] (25) COLLATE French_CI_AS NULL ,
[DST_EMAIL] [varchar] (128) COLLATE French_CI_AS NOT NULL
) ON [PRIMARY]
GO
CREATE TABLE [dbo].[T_ENVOYE_EVO] (
[MSG_ID] [int] NOT NULL ,
[DST_ID] [int] NOT NULL ,
[TEV_ID] [int] NOT NULL
) ON [PRIMARY]
GO
CREATE TABLE [dbo].[T_MESSAGE_MSG] (
[MSG_ID] [int] IDENTITY (1, 1) NOT NULL ,
[MSG_TITRE] [varchar] (128) COLLATE French_CI_AS NOT NULL ,
[MSG_TEXTE] [varchar] (5000) COLLATE French_CI_AS NOT NULL ,
[MSG_DH_INSERE] [datetime] NOT NULL ,
[MSG_DH_ENVOI] [datetime] NULL ,
[MSG_FAILED] [bit] NOT NULL
) ON [PRIMARY]
GO
CREATE TABLE [dbo].[T_TYPE_ENVOI_TEV] (
[TEV_ID] [int] IDENTITY (1, 1) NOT NULL ,
[TEV_CODE] [char] (3) COLLATE French_CI_AS NOT NULL ,
[TEV_LIBELLE] [varchar] (20) COLLATE French_CI_AS NOT NULL
) ON [PRIMARY]
GO
INSERT INTO T_TYPE_ENVOI_TEV VALUES ('To','Principal')
INSERT INTO T_TYPE_ENVOI_TEV VALUES ('Cc','Copie')
INSERT INTO T_TYPE_ENVOI_TEV VALUES ('Bcc','Copie Cachée')
GO
CREATE PROCEDURE [dbo].[P_MESSAGE_SEND]
AS
Declare @From varchar(128), @To varchar(128), @Subject varchar(128),
@Body varchar(5000), @Cc varchar(500), @Bcc varchar(500)
Declare @iMsg int
Declare @hr int
Declare @source varchar(255)
Declare @description varchar(500)
Declare @output varchar(1000)
Declare @ID_MSG INT
EXEC @hr = sp_OACreate 'CDO.Message', @iMsg OUT
EXEC @hr = sp_OASetProperty @iMsg, 'Configuration.fields("http://schemas.microsoft.com/cdo/configuration/sendusing").Value','2'
EXEC @hr = sp_OASetProperty @iMsg, 'Configuration.fields("http://schemas.microsoft.com/cdo/configuration/smtpserver").Value', '???'
EXEC @hr = sp_OAMethod @iMsg, 'Configuration.Fields.Update', null
WHILE (SELECT COUNT(*) FROM T_MESSAGE_MSG WHERE MSG_DH_ENVOI IS NULL) > 0
BEGIN
SELECT TOP 1 @ID_MSG=MSG_ID, @Subject=MSG_TITRE ,@Body=MSG_TEXTE FROM T_MESSAGE_MSG WHERE MSG_DH_ENVOI IS NULL
SET @To=''
SELECT @To=@To + DST_EMAIL + ', '
FROM T_DESTINATAIRE_DST DST INNER JOIN T_ENVOYE_EVO EVO ON DST.DST_ID=EVO.DST_ID
INNER JOIN T_TYPE_ENVOI_TEV TEV ON EVO.TEV_ID=TEV.TEV_ID
WHERE MSG_ID=@ID_MSG AND UPPER(TEV_CODE)='TO'
SET @To=SUBSTRING(@To,1,LEN(@To)-1)
SET @Cc=''
SELECT @Cc=@Cc + DST_EMAIL + ', '
FROM T_DESTINATAIRE_DST DST INNER JOIN T_ENVOYE_EVO EVO ON DST.DST_ID=EVO.DST_ID
INNER JOIN T_TYPE_ENVOI_TEV TEV ON EVO.TEV_ID=TEV.TEV_ID
WHERE MSG_ID=@ID_MSG AND UPPER(TEV_CODE)='CC'
SET @Cc=SUBSTRING(@Cc,1,LEN(@Cc)-1)
SET @Bcc=''
SELECT @Bcc=@Bcc + DST_EMAIL + ', '
FROM T_DESTINATAIRE_DST DST INNER JOIN T_ENVOYE_EVO EVO ON DST.DST_ID=EVO.DST_ID
INNER JOIN T_TYPE_ENVOI_TEV TEV ON EVO.TEV_ID=TEV.TEV_ID
WHERE MSG_ID=@ID_MSG AND UPPER(TEV_CODE)='BCC'
SET @Bcc=SUBSTRING(@Bcc,1,LEN(@Bcc)-1)
SET @From='!!!'
EXEC @hr = sp_OASetProperty @iMsg, 'To', @To
EXEC @hr = sp_OASetProperty @iMsg, 'From', @From
IF @Cc<>'' EXEC @hr = sp_OASetProperty @iMsg, 'Cc', @Cc
IF @Bcc <>'' EXEC @hr = sp_OASetProperty @iMsg, 'Bcc', @Bcc
EXEC @hr = sp_OASetProperty @iMsg, 'Subject', @Subject
EXEC @hr = sp_OASetProperty @iMsg, 'TextBody', @Body
EXEC @hr = sp_OAMethod @iMsg, 'Send', NULL
IF @hr <>0
UPDATE T_MESSAGE_MSG
SET MSG_DH_ENVOI=CURRENT_TIMESTAMP,
MSG_FAILED=1
WHERE MSG_ID=@ID_MSG
ELSE
UPDATE T_MESSAGE_MSG
SET MSG_DH_ENVOI=CURRENT_TIMESTAMP
WHERE MSG_ID=@ID_MSG
EXEC @hr = sp_OADestroy @iMsg
END
GO
CREATE PROCEDURE P_MESSAGE_SET @TITRE VARCHAR(128), @TEXTE VARCHAR(5000),
@DEST1 CHAR(3),
@DEST2 CHAR(3), @TEVCODE2 CHAR(3),
@DEST3 CHAR(3), @TEVCODE3 CHAR(3),
@DEST4 CHAR(3), @TEVCODE4 CHAR(3)
AS
IF @TITRE IS NULL OR @TEXTE IS NULL OR @DEST1 IS NULL RETURN
DECLARE @ID_MESSAGE INT
BEGIN TRAN
INSERT INTO T_MESSAGE_MSG (MSG_TITRE, MSG_TEXTE)
VALUES (@TITRE, @TEXTE)
IF @@ERROR<>0 GOTO TRAITE_ERREUR
SET @ID_MESSAGE=@@IDENTITY
INSERT INTO T_ENVOYE_EVO
SELECT @ID_MESSAGE,
(SELECT DST_ID
FROM T_DESTINATAIRE_DST
WHERE UPPER(DST_CODE)=UPPER(@DEST1)),
(SELECT TEV_ID
FROM T_TYPE_ENVOI_TEV
WHERE UPPER(TEV_CODE)='TO')
IF @@ERROR<>0 GOTO TRAITE_ERREUR
IF EXISTS(SELECT * FROM T_DESTINATAIRE_DST WHERE UPPER(DST_CODE)= UPPER(@DEST2))
BEGIN
INSERT INTO T_ENVOYE_EVO
SELECT @ID_MESSAGE,
(SELECT DST_ID
FROM T_DESTINATAIRE_DST
WHERE UPPER(DST_CODE)=UPPER(@DEST2)),
(SELECT TEV_ID
FROM T_TYPE_ENVOI_TEV
WHERE UPPER(TEV_CODE)=UPPER(@TEVCODE2))
IF @@ERROR<>0 GOTO TRAITE_ERREUR
END
IF EXISTS(SELECT * FROM T_DESTINATAIRE_DST WHERE UPPER(DST_CODE)= UPPER(@DEST3))
BEGIN
INSERT INTO T_ENVOYE_EVO
SELECT @ID_MESSAGE,
(SELECT DST_ID
FROM T_DESTINATAIRE_DST
WHERE UPPER(DST_CODE)=UPPER(@DEST3)),
(SELECT TEV_ID
FROM T_TYPE_ENVOI_TEV
WHERE UPPER(TEV_CODE)=UPPER(@TEVCODE3))
IF @@ERROR<>0 GOTO TRAITE_ERREUR
END
IF EXISTS(SELECT * FROM T_DESTINATAIRE_DST WHERE UPPER(DST_CODE)= UPPER(@DEST4))
BEGIN
INSERT INTO T_ENVOYE_EVO
SELECT @ID_MESSAGE,
(SELECT DST_ID
FROM T_DESTINATAIRE_DST
WHERE UPPER(DST_CODE)=UPPER(@DEST4)),
(SELECT TEV_ID
FROM T_TYPE_ENVOI_TEV
WHERE UPPER(TEV_CODE)=UPPER(@TEVCODE4))
IF @@ERROR<>0 GOTO TRAITE_ERREUR
END
COMMIT TRAN
RETURN
TRAITE_ERREUR:
ROLLBACK TRAN
GO