Web design and hosting, database, cloud and social media solutions that deliver business results
  • Soluzioni aziendali
    • automazione dei processi robotici
    • Software
    • Servizi database
      • Aggiornamento del server e servizi DBA
      • Integrazione dei dati
      • Power BI
      • Servizi di Datawarehouse
    • Sito Web Design
      • Design del logo
      • Gateway di pagamento
      • Localizzazione e traduzione web
      • Ottimizzazione del sito web
      • Sicurezza del sito
      • Strumenti tecnici
    • Servizi per gli affari
      • Microsoft Azure
      • Servizi Google Cloud
      • Servizi Web Amazon
    • Microsoft Office
    • Servizi di consulenza e gestione dei social media
  • Accademia
    • Il nostro ambiente di prova
    • Imparare a usare i database
      • Le basi
      • Ottieni una query aperta
      • Piano di manutenzione di SQL Server 2008
      • Utilizzo dei dati di SQL Server
      • Utilizzo delle date di SQL Server
      • Utilizzo delle funzioni di SQL Server
      • Utilizzo di SQL Server Pivot-Unpivot
      • Strumenti
    • Imparare il web design
      • Costruire il sistema di gestione dei contenuti di Ousia
      • ASP-NET
      • CSS
      • Utilizzo di JavaScript
    • Usando i social media
      • Chiedere una recensione su Google
      • Dimensioni delle immagini dei social media
      • Modifica di un account Facebook da personale a aziendale
      • Scegliere dove concentrare lo sforzo sui social media
      • Utilizzo dei metadati per impostare le immagini dei social media
    • Imparare a usare il cloud e i servizi informatici
      • Errore dell'utilità di pianificazione 2147943645
      • Richiesta SSL e generazione di file PFX in OpenSSL Simple Steps
  • Chi Siamo
    • Carriere
      • Traduttore inglese-portoghese
      • Traduttore inglese-spagnolo
    • Portfolio
    • Squadra
      • Adrian Anandan
      • Alì Al Amine
      • Ayse Hur
      • Chester Copperpot
      • Gavin Clayton
      • Sai Gangu
      • Suneel Kumar
      • Surya Mukkamala
Deutsch (DE)English (EN-US)English (EN-GB)हिंदी (HI)italiano (IT)日本語 (JA)

Nome file a generazione dinamica

Come utilizzare SQL Server per creare dinamicamente nomi di file variabili, associarlo a una tabella e utilizzare i dati in un esempio del mondo reale

Context

In the process of building an automated export process for one of our clients we came across the need to generate file names on the fly. To do this we knew that it would need to be a hard coded function as you can't use variables within DATEPART, but it was still something that we wanted to make as easy as possible to use. Allowing the client to put variables in the files names would be the way forward.

To start with, add the following two functions. We've popped some links in to give you more information on how they work.

Pre-Requisites

ALTER FUNCTION [dbo].[TextPad](@PadChar CHAR(1),@PadValue NVARCHAR(100),@PadLen INT) RETURNS NVARCHAR(100) WITH SCHEMABINDING AS BEGINRETURN ISNULL(REPLICATE(@PadChar,@PadLen-LEN(@PadValue))+@PadValue,LEFT(@PadValue,@PadLen))ENDGOALTER FUNCTION [App].[TextToRows](@Delim NVARCHAR(10),@Value NVARCHAR(MAX))--Delimeter and Search StringRETURNS @Table TABLE(WordInt BIGINT IDENTITY(1,1) PRIMARY KEY,WordStr NVARCHAR(MAX)) WITH SCHEMABINDING --Return TableAS BEGIN--IF @Trim=1 SET @Value=LTRIM(RTRIM(@Value))DECLARE @CurPos BIGINT=0DECLARE @NextPos BIGINT=CHARINDEX(@Delim,@Value,@CurPos+1+LEN(@Delim))WHILE @NextPos>0 BEGININSERT INTO @Table(WordStr) SELECT SUBSTRING(@Value,@CurPos+1,(@NextPos-@CurPos)-1)SET @CurPos=@NextPosSET @NextPos=CHARINDEX(@Delim,@Value,@CurPos+1+LEN(@Delim))ENDINSERT INTO @Table(WordStr) SELECT RIGHT(@Value,LEN(@Value)-@CurPos)RETURNENDGO

Text to Rows Function

Suddivisione di testo o BLOB in righe e tabelle di dati in SQL Server

Text Padding Function

Aggiunta di riempimento del testo con una funzione SQL

Dynamic File Name Function

Now that we have the basics in, we can move to the next stage. Those of you who are eagle eyed may have noticed the SCHEMABINDING part in the statement. As the eventual aim is to have this set as a column, every child function will need schema binding turned on.

It's a fairly simple function that uses a set of replaces, but in an order from longest to shortest. Text replacement candidates are worked out by two text two rows functions that split the text up into new rows.

Where we have put the date in hardcoded for testing, you can use GETDATE() for the machine date, or GETUTCDATE() for Universal Date

SQL

ALTER FUNCTION UpdFileName(@N NVARCHAR(MAX)) RETURNS NVARCHAR(MAX) WITH SCHEMABINDING AS BEGINDECLARE @D DATETIME='2021-06-19 15:00:00',@R NVARCHAR(MAX)=''(SELECT @R=@R+(CASE WHEN y.WordInt=1 AND x.WordInt>1 THEN  REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( y.WordStr, 'yyyy',[dbo].[TextPad]('0',DATEPART(YEAR,@D),4) COLLATE latin1_general_cs_as), 'dd',[dbo].[TextPad]('0',DATEPART(DAY,@D),2) COLLATE latin1_general_cs_as), 'MM',[dbo].[TextPad]('0',DATEPART(MONTH,@D),2) COLLATE latin1_general_cs_as), 'mm',[dbo].[TextPad]('0',DATEPART(MINUTE,@D),2) COLLATE latin1_general_cs_as), 'hh',[dbo].[TextPad]('0',(CASE WHEN DATEPART(HOUR,@D)>12 THEN DATEPART(HOUR,@D)-12 ELSE DATEPART(HOUR,@D) END),2) COLLATE latin1_general_cs_as), 'HH',[dbo].[TextPad]('0',DATEPART(HOUR,@D),2) COLLATE latin1_general_cs_as), 'ss',[dbo].[TextPad]('0',DATEPART(SECOND,@D),2) COLLATE latin1_general_cs_as), 'qq',[dbo].[TextPad]('0',DATEPART(QUARTER,@D),2) COLLATE latin1_general_cs_as), 'wk',[dbo].[TextPad]('0',DATEPART(WEEK,@D),2) COLLATE latin1_general_cs_as), 'yy',RIGHT(CONVERT(NVARCHAR(10),DATEPART(YEAR,@D)),2) COLLATE latin1_general_cs_as), 'ms',CONVERT(NVARCHAR(10),DATEPART(MILLISECOND,@D)) COLLATE latin1_general_cs_as), 'dy',CONVERT(NVARCHAR(10),DATEPART(DAYOFYEAR,@D)) COLLATE latin1_general_cs_as), 'dw',CONVERT(NVARCHAR(10),DATEPART(WEEKDAY,@D)) COLLATE latin1_general_cs_as), 's',CONVERT(NVARCHAR(10),DATEPART(SECOND,@D)) COLLATE latin1_general_cs_as), 'h',CONVERT(NVARCHAR(10),(CASE WHEN DATEPART(HOUR,@D)>12 THEN DATEPART(HOUR,@D)-12 ELSE DATEPART(HOUR,@D) END)) COLLATE latin1_general_cs_as), 'H',CONVERT(NVARCHAR(10),DATEPART(HOUR,@D)) COLLATE latin1_general_cs_as), 'M',CONVERT(NVARCHAR(10),DATEPART(MONTH,@D)) COLLATE latin1_general_cs_as), 'm',CONVERT(NVARCHAR(10),DATEPART(MONTH,@D)) COLLATE latin1_general_cs_as), 'w',CONVERT(NVARCHAR(10),DATEPART(WEEKDAY,@D)) COLLATE latin1_general_cs_as), 'd',CONVERT(NVARCHAR(10),DATEPART(DAY,@D),2) COLLATE latin1_general_cs_as), 'n',CONVERT(NVARCHAR(10),DATEPART(MINUTE,@D),2) COLLATE latin1_general_cs_as), 'y',CONVERT(NVARCHAR(10),DATEPART(DAYOFYEAR,@D)) COLLATE latin1_general_cs_as) ELSE y.WordStr END) FROM App.TextToRows('{',@N) xOUTER APPLY App.TextToRows('}',WordStr) y)RETURN @RENDGO

Bind to a table

The final stage is binding it to a table. To do that simply declare the column name and then use an AS statement and the function name with any variables required. We've popped some demo output below too.

SQL

FilePath.png
CREATE TABLE FN(FN NVARCHAR(MAX),FP AS dbo.UpdFileName(FN))GOINSERT INTO FN SELECT 'TestFile{dd_MM_yyyy_hh_mm_ss}.csv'INSERT INTO FN SELECT 'TestFile{dd_MM_yyyy_HH_mm_ss}.csv'INSERT INTO FN SELECT 'TestFile_{qq dMyy h}.txt'INSERT INTO FN SELECT 'TestFile_{qq dMyy H}.txt'SELECT * FROM FN

Author

Copyright Claytabase Ltd 2020

Registered in England and Wales 08985867

Site Links

RSSLoginLink Cookie PolicyMappa del sito

Social Media

facebook.com/Claytabaseinstagram.com/claytabase/twitter.com/Claytabaselinkedin.com/company/claytabase-ltd

Get in Touch

+442392064871info@claytabase.comClaytabase Ltd, Unit 3d, Rink Road Industrial Estate, PO33 2LT, United Kingdom

Partnered With

Le impostazioni di questo sito sono impostate per consentire tutti i cookie. Questi possono essere modificati sulla nostra pagina politica e le impostazioni dei cookie. Continuando a utilizzare questo sito l'utente accetta l'utilizzo dei cookie.
Ousia Logo
Logout
Ousia CMS Loader